Skip to main content
Ctrl+K

Tantor Special Edition 1C 16.10 documentation

Table of contents:

  • Preface
    • 1.  What Is Tantor SE-1C?
    • 2. A Brief History of PostgreSQL
    • 3. What are the differences between Tantor SE 1C 16 and PostgreSQL 16
    • 4. 1C improvements
    • 5. Conventions
    • 6. Bug Reporting Guidelines
  • Part I. Tutorial
    • Chapter 1. Synopsis
      • 1.1. Synopsis
      • 1.2. Architectural Fundamentals
      • 1.3. Creating a Database
      • 1.4. Accessing a Database
    • Chapter 2. The SQL Language
      • 2.1. Introduction
      • 2.2. Concepts
      • 2.3. Creating a New Table
      • 2.4. Populating a Table With Rows
      • 2.5. Querying a Table
      • 2.6. Joins Between Tables
      • 2.7. Aggregate Functions
      • 2.8. Updates
      • 2.9. Deletions
    • Chapter 3. Advanced Features
      • 3.1. Introduction
      • 3.2. Views
      • 3.3. Foreign Keys
      • 3.4. Transactions
      • 3.5. Window Functions
      • 3.6. Inheritance
      • 3.7. Conclusion
  • Part II. The SQL Language
    • Chapter 4. SQL Syntax
      • 4.1. Lexical Structure
      • 4.2. Value Expressions
      • 4.3. Calling Functions
    • Chapter 5. Data Definition
      • 5.1. Table Basics
      • 5.2. Default Values
      • 5.3. Generated Columns
      • 5.4. Constraints
      • 5.5. System Columns
      • 5.6. Modifying Tables
      • 5.7. Privileges
      • 5.8. Row Security Policies
      • 5.9. Schemas
      • 5.10. Inheritance
      • 5.11. Table Partitioning
      • 5.12. Foreign Data
      • 5.13. Other Database Objects
      • 5.14. Dependency Tracking
    • Chapter 6. Data Manipulation
      • 6.1. Inserting Data
      • 6.2. Updating Data
      • 6.3. Deleting Data
      • 6.4. Returning Data from Modified Rows
    • Chapter 7. Queries
      • 7.1. Overview
      • 7.2. Table Expressions
      • 7.3. Select Lists
      • 7.4. Combining Queries (UNION, INTERSECT, EXCEPT)
      • 7.5. Sorting Rows (ORDER BY)
      • 7.6. LIMIT and OFFSET
      • 7.7. VALUES Lists
      • 7.8. WITH Queries (Common Table Expressions)
    • Chapter 8. Data Types
      • 8.1. Numeric Types
      • 8.2. Monetary Types
      • 8.3. Character Types
      • 8.4. Binary Data Types
      • 8.5. Date/Time Types
      • 8.6. Boolean Type
      • 8.7. Enumerated Types
      • 8.8. Geometric Types
      • 8.9. Network Address Types
      • 8.10. Bit String Types
      • 8.11. Text Search Types
      • 8.12. UUID Type
      • 8.13. XML Type
      • 8.14. JSON Types
      • 8.15. Arrays
      • 8.16. Composite Types
      • 8.17. Range Types
      • 8.18. Domain Types
      • 8.19. Object Identifier Types
      • 8.20. pg_lsn Type
      • 8.21. Pseudo-Types
    • Chapter 9. Functions and Operators
      • 9.1. Logical Operators
      • 9.2. Comparison Functions and Operators
      • 9.3. Mathematical Functions and Operators
      • 9.4. String Functions and Operators
      • 9.5. Binary String Functions and Operators
      • 9.6. Bit String Functions and Operators
      • 9.7. Pattern Matching
      • 9.8. Data Type Formatting Functions
      • 9.9. Date/Time Functions and Operators
      • 9.10. Enum Support Functions
      • 9.11. Geometric Functions and Operators
      • 9.12. Network Address Functions and Operators
      • 9.13. Text Search Functions and Operators
      • 9.14. UUID Functions
      • 9.15. XML Functions
      • 9.16. JSON Functions and Operators
      • 9.17. Sequence Manipulation Functions
      • 9.18. Conditional Expressions
      • 9.19. Array Functions and Operators
      • 9.20. Range/Multirange Functions and Operators
      • 9.21. Aggregate Functions
      • 9.22. Window Functions
      • 9.23. Subquery Expressions
      • 9.24. Row and Array Comparisons
      • 9.25. Set Returning Functions
      • 9.26. System Information Functions and Operators
      • 9.27. System Administration Functions
      • 9.28. Trigger Functions
      • 9.29. Event Trigger Functions
      • 9.30. Statistics Information Functions
    • Chapter 10. Type Conversion
      • 10.1. Overview
      • 10.2. Operators
      • 10.3. Functions
      • 10.4. Value Storage
      • 10.5. UNION, CASE, and Related Constructs
      • 10.6. SELECT Output Columns
    • Chapter 11. Indexes
      • 11.1. Introduction
      • 11.2. Index Types
      • 11.3. Multicolumn Indexes
      • 11.4. Indexes and ORDER BY
      • 11.5. Combining Multiple Indexes
      • 11.6. Unique Indexes
      • 11.7. Indexes on Expressions
      • 11.8. Partial Indexes
      • 11.9. Index-Only Scans and Covering Indexes
      • 11.10. Operator Classes and Operator Families
      • 11.11. Indexes and Collations
      • 11.12. Examining Index Usage
    • Chapter 12. Full Text Search
      • 12.1. Introduction
      • 12.2. Tables and Indexes
      • 12.3. Controlling Text Search
      • 12.4. Additional Features
      • 12.5. Parsers
      • 12.6. Dictionaries
      • 12.7. Configuration Example
      • 12.8. Testing and Debugging Text Search
      • 12.9. Preferred Index Types for Text Search
      • 12.10. psql Support
      • 12.11. Limitations
    • Chapter 13. Concurrency Control
      • 13.1. Introduction
      • 13.2. Transaction Isolation
      • 13.3. Explicit Locking
      • 13.4. Data Consistency Checks at the Application Level
      • 13.5. Serialization Failure Handling
      • 13.6. Caveats
      • 13.7. Locking and Indexes
    • Chapter 14. Performance Tips
      • 14.1. Using EXPLAIN
      • 14.2. Statistics Used by the Planner
      • 14.3. Controlling the Planner with Explicit JOIN Clauses
      • 14.4. Populating a Database
      • 14.5. Non-Durable Settings
    • Chapter 15. Parallel Query
      • 15.1. How Parallel Query Works
      • 15.2. When Can Parallel Query Be Used?
      • 15.3. Parallel Plans
      • 15.4. Parallel Safety
  • Part III. Server Administration
    • Chapter 16. Installation from Binaries
      • 16.1. Downloading and Executing the Installer
      • 16.2. Installer Options
    • Chapter 17. Server Setup and Operation
      • 17.1. The Tantor SE-1C User Account
      • 17.2. Creating a Database Cluster
      • 17.3. Starting the Database Server
      • 17.4. Managing Kernel Resources
      • 17.5. Shutting Down the Server
      • 17.6. Upgrading a Tantor SE-1C Cluster
      • 17.7. Preventing Server Spoofing
      • 17.8. Encryption Options
      • 17.9. Secure TCP/IP Connections with SSL
      • 17.10. Secure TCP/IP Connections with GSSAPI Encryption
      • 17.11. Secure TCP/IP Connections with SSH Tunnels
      • 17.12. Registering Event Log on Windows
    • Chapter 18. Server Configuration
      • 18.1. Setting Parameters
      • 18.2. File Locations
      • 18.3. Connections and Authentication
      • 18.4. Resource Consumption
      • 18.5. Write Ahead Log
      • 18.6. Replication
      • 18.7. Query Planning
      • 18.8. Error Reporting and Logging
      • 18.9. Run-time Statistics
      • 18.10. Automatic Vacuuming
      • 18.11. Client Connection Defaults
      • 18.12. Lock Management
      • 18.13. Version and Platform Compatibility
      • 18.14. Error Handling
      • 18.15. Preset Options
      • 18.16. Customized Options
      • 18.17. Developer Options
      • 18.18. Short Options
    • Chapter 19. Client Authentication
      • 19.1. The pg_hba.conf File
      • 19.2. User Name Maps
      • 19.3. Authentication Methods
      • 19.4. Trust Authentication
      • 19.5. Password Authentication
      • 19.6. GSSAPI Authentication
      • 19.7. SSPI Authentication
      • 19.8. Ident Authentication
      • 19.9. Peer Authentication
      • 19.10. LDAP Authentication
      • 19.11. RADIUS Authentication
      • 19.12. Certificate Authentication
      • 19.13. PAM Authentication
      • 19.14. BSD Authentication
      • 19.15. Authentication Problems
    • Chapter 20. Database Roles
      • 20.1. Database Roles
      • 20.2. Role Attributes
      • 20.3. Role Membership
      • 20.4. Dropping Roles
      • 20.5. Predefined Roles
      • 20.6. Function Security
    • Chapter 21. Managing Databases
      • 21.1. Overview
      • 21.2. Creating a Database
      • 21.3. Template Databases
      • 21.4. Database Configuration
      • 21.5. Destroying a Database
      • 21.6. Tablespaces
    • Chapter 22. Localization
      • 22.1. Locale Support
      • 22.2. Collation Support
      • 22.3. Character Set Support
    • Chapter 23. Routine Database Maintenance Tasks
      • 23.1. Routine Vacuuming
      • 23.2. Routine Reindexing
      • 23.3. Log File Maintenance
    • Chapter 24. Backup and Restore
      • 24.1. SQL Dump
      • 24.2. File System Level Backup
      • 24.3. Continuous Archiving and Point-in-Time Recovery (PITR)
    • Chapter 25. High Availability, Load Balancing, and Replication
      • 25.1. Comparison of Different Solutions
      • 25.2. Log-Shipping Standby Servers
      • 25.3. Failover
      • 25.4. Hot Standby
    • Chapter 26. Monitoring Database Activity
      • 26.1. Standard Unix Tools
      • 26.2. The Cumulative Statistics System
      • 26.3. Viewing Locks
      • 26.4. Progress Reporting
      • 26.5. Dynamic Tracing
    • Chapter 27. Monitoring Disk Usage
      • 27.1. Determining Disk Usage
      • 27.2. Disk Full Failure
    • Chapter 28. Reliability and the Write-Ahead Log
      • 28.1. Reliability
      • 28.2. Data Checksums
      • 28.3. Write-Ahead Logging (WAL)
      • 28.4. Asynchronous Commit
      • 28.5. WAL Configuration
      • 28.6. WAL Internals
    • Chapter 29. Logical Replication
      • 29.1. Publication
      • 29.2. Subscription
      • 29.3. Row Filters
      • 29.4. Column Lists
      • 29.5. Conflicts
      • 29.6. Restrictions
      • 29.7. Architecture
      • 29.8. Monitoring
      • 29.9. Security
      • 29.10. Configuration Settings
      • 29.11. Quick Setup
    • Chapter 30. Just-in-Time Compilation (JIT)
      • 30.1. What Is JIT compilation?
      • 30.2. When to JIT?
      • 30.3. Configuration
      • 30.4. Extensibility
  • Part IV. Client Interfaces
    • Chapter 31. libpq — C Library
      • 31.1. Database Connection Control Functions
      • 31.2. Connection Status Functions
      • 31.3. Command Execution Functions
      • 31.4. Asynchronous Command Processing
      • 31.5. Pipeline Mode
      • 31.6. Retrieving Query Results Row-by-Row
      • 31.7. Canceling Queries in Progress
      • 31.8. The Fast-Path Interface
      • 31.9. Asynchronous Notification
      • 31.10. Functions Associated with the COPY Command
      • 31.11. Control Functions
      • 31.12. Miscellaneous Functions
      • 31.13. Notice Processing
      • 31.14. Event System
      • 31.15. Environment Variables
      • 31.16. The Password File
      • 31.17. The Connection Service File
      • 31.18. LDAP Lookup of Connection Parameters
      • 31.19. SSL Support
      • 31.20. Behavior in Threaded Programs
      • 31.21. Building libpq Programs
      • 31.22. Example Programs
    • Chapter 32. Large Objects
      • 32.1. Introduction
      • 32.2. Implementation Features
      • 32.3. Client Interfaces
      • 32.4. Server-Side Functions
      • 32.5. Example Program
    • Chapter 33. ECPG — Embedded SQL in C
      • 33.1. The Concept
      • 33.2. Managing Database Connections
      • 33.3. Running SQL Commands
      • 33.4. Using Host Variables
      • 33.5. Dynamic SQL
      • 33.6. pgtypes Library
      • 33.7. Using Descriptor Areas
      • 33.8. Error Handling
      • 33.9. Preprocessor Directives
      • 33.10. Processing Embedded SQL Programs
      • 33.11. Library Functions
      • 33.12. Large Objects
      • 33.13. C++ Applications
      • 33.14. Embedded SQL Commands
      • 33.15. Informix Compatibility Mode
      • 33.16. Oracle Compatibility Mode
      • 33.17. Internals
    • Chapter 34. The Information Schema
      • 34.1. The Schema
      • 34.2. Data Types
      • 34.3. information_schema_catalog_name
      • 34.4. administrable_role_​authorizations
      • 34.5. applicable_roles
      • 34.6. attributes
      • 34.7. character_sets
      • 34.8. check_constraint_routine_usage
      • 34.9. check_constraints
      • 34.10. collations
      • 34.11. collation_character_set_​applicability
      • 34.12. column_column_usage
      • 34.13. column_domain_usage
      • 34.14. column_options
      • 34.15. column_privileges
      • 34.16. column_udt_usage
      • 34.17. columns
      • 34.18. constraint_column_usage
      • 34.19. constraint_table_usage
      • 34.20. data_type_privileges
      • 34.21. domain_constraints
      • 34.22. domain_udt_usage
      • 34.23. domains
      • 34.24. element_types
      • 34.25. enabled_roles
      • 34.26. foreign_data_wrapper_options
      • 34.27. foreign_data_wrappers
      • 34.28. foreign_server_options
      • 34.29. foreign_servers
      • 34.30. foreign_table_options
      • 34.31. foreign_tables
      • 34.32. key_column_usage
      • 34.33. parameters
      • 34.34. referential_constraints
      • 34.35. role_column_grants
      • 34.36. role_routine_grants
      • 34.37. role_table_grants
      • 34.38. role_udt_grants
      • 34.39. role_usage_grants
      • 34.40. routine_column_usage
      • 34.41. routine_privileges
      • 34.42. routine_routine_usage
      • 34.43. routine_sequence_usage
      • 34.44. routine_table_usage
      • 34.45. routines
      • 34.46. schemata
      • 34.47. sequences
      • 34.48. sql_features
      • 34.49. sql_implementation_info
      • 34.50. sql_parts
      • 34.51. sql_sizing
      • 34.52. table_constraints
      • 34.53. table_privileges
      • 34.54. tables
      • 34.55. transforms
      • 34.56. triggered_update_columns
      • 34.57. triggers
      • 34.58. udt_privileges
      • 34.59. usage_privileges
      • 34.60. user_defined_types
      • 34.61. user_mapping_options
      • 34.62. user_mappings
      • 34.63. view_column_usage
      • 34.64. view_routine_usage
      • 34.65. view_table_usage
      • 34.66. views
  • Part V. Server Programming
    • Chapter 35. Extending SQL
      • 35.1. How Extensibility Works
      • 35.2. The Tantor SE-1C Type System
      • 35.3. User-Defined Functions
      • 35.4. User-Defined Procedures
      • 35.5. Query Language (SQL) Functions
      • 35.6. Function Overloading
      • 35.7. Function Volatility Categories
      • 35.8. Procedural Language Functions
      • 35.9. Internal Functions
      • 35.10. Function Optimization Information
      • 35.11. User-Defined Aggregates
      • 35.12. User-Defined Types
      • 35.13. User-Defined Operators
      • 35.14. Operator Optimization Information
      • 35.15. Interfacing Extensions to Indexes
      • 35.16. Packaging Related Objects into an Extension
      • 35.17. Extension Building Infrastructure
    • Chapter 36. Triggers
      • 36.1. Overview of Trigger Behavior
      • 36.2. Visibility of Data Changes
      • 36.3. Writing Trigger Functions in C
      • 36.4. A Complete Trigger Example
    • Chapter 37. Event Triggers
      • 37.1. Overview of Event Trigger Behavior
      • 37.2. Event Trigger Firing Matrix
      • 37.3. Writing Event Trigger Functions in C
      • 37.4. A Complete Event Trigger Example
      • 37.5. A Table Rewrite Event Trigger Example
    • Chapter 38. The Rule System
      • 38.1. The Query Tree
      • 38.2. Views and the Rule System
      • 38.3. Materialized Views
      • 38.4. Rules on INSERT, UPDATE, and DELETE
      • 38.5. Rules and Privileges
      • 38.6. Rules and Command Status
      • 38.7. Rules Versus Triggers
    • Chapter 39. Procedural Languages
      • 39.1. Installing Procedural Languages
    • Chapter 40. PL/pgSQL — SQL Procedural Language
      • 40.1. Overview
      • 40.2. Structure of PL/pgSQL
      • 40.3. Declarations
      • 40.4. Expressions
      • 40.5. Basic Statements
      • 40.6. Control Structures
      • 40.7. Cursors
      • 40.8. Transaction Management
      • 40.9. Errors and Messages
      • 40.10. Trigger Functions
      • 40.11. PL/pgSQL under the Hood
      • 40.12. Tips for Developing in PL/pgSQL
      • 40.13. Porting from Oracle PL/SQL
    • Chapter 41. PL/Tcl — Tcl Procedural Language
      • 41.1. Overview
      • 41.2. PL/Tcl Functions and Arguments
      • 41.3. Data Values in PL/Tcl
      • 41.4. Global Data in PL/Tcl
      • 41.5. Database Access from PL/Tcl
      • 41.6. Trigger Functions in PL/Tcl
      • 41.7. Event Trigger Functions in PL/Tcl
      • 41.8. Error Handling in PL/Tcl
      • 41.9. Explicit Subtransactions in PL/Tcl
      • 41.10. Transaction Management
      • 41.11. PL/Tcl Configuration
      • 41.12. Tcl Procedure Names
    • Chapter 42. PL/Perl — Perl Procedural Language
      • 42.1. PL/Perl Functions and Arguments
      • 42.2. Data Values in PL/Perl
      • 42.3. Built-in Functions
      • 42.4. Global Values in PL/Perl
      • 42.5. Trusted and Untrusted PL/Perl
      • 42.6. PL/Perl Triggers
      • 42.7. PL/Perl Event Triggers
      • 42.8. PL/Perl Under the Hood
    • Chapter 43. PL/Python — Python Procedural Language
      • 43.1. PL/Python Functions
      • 43.2. Data Values
      • 43.3. Sharing Data
      • 43.4. Anonymous Code Blocks
      • 43.5. Trigger Functions
      • 43.6. Database Access
      • 43.7. Explicit Subtransactions
      • 43.8. Transaction Management
      • 43.9. Utility Functions
      • 43.10. Python 2 vs. Python 3
      • 43.11. Environment Variables
    • Chapter 44. Server Programming Interface
      • 44.1. Interface Functions
      • 44.2. Interface Support Functions
      • 44.3. Memory Management
      • 44.4. Transaction Management
      • 44.5. Visibility of Data Changes
      • 44.6. Examples
    • Chapter 45. Background Worker Processes
    • Chapter 46. Logical Decoding
      • 46.1. Logical Decoding Examples
      • 46.2. Logical Decoding Concepts
      • 46.3. Streaming Replication Protocol Interface
      • 46.4. Logical Decoding SQL Interface
      • 46.5. System Catalogs Related to Logical Decoding
      • 46.6. Logical Decoding Output Plugins
      • 46.7. Logical Decoding Output Writers
      • 46.8. Synchronous Replication Support for Logical Decoding
      • 46.9. Streaming of Large Transactions for Logical Decoding
      • 46.10. Two-phase Commit Support for Logical Decoding
    • Chapter 47. Replication Progress Tracking
    • Chapter 48. Archive Modules
      • 48.1. Initialization Functions
      • 48.2. Archive Module Callbacks
  • Part VI. Reference
    • SQL Commands
    • PostgreSQL Client Applications
    • PostgreSQL Server Applications
  • Part VII. Internals
    • Chapter 49. Overview of PostgreSQL Internals
      • 49.1. The Path of a Query
      • 49.2. How Connections Are Established
      • 49.3. The Parser Stage
      • 49.4. The Tantor SE-1C Rule System
      • 49.5. Planner/Optimizer
      • 49.6. Executor
    • Chapter 50. System Catalogs
      • 50.1. Overview
      • 50.2. pg_aggregate
      • 50.3. pg_am
      • 50.4. pg_amop
      • 50.5. pg_amproc
      • 50.6. pg_attrdef
      • 50.7. pg_attribute
      • 50.8. pg_authid
      • 50.9. pg_auth_members
      • 50.10. pg_cast
      • 50.11. pg_class
      • 50.12. pg_collation
      • 50.13. pg_constraint
      • 50.14. pg_conversion
      • 50.15. pg_database
      • 50.16. pg_db_role_setting
      • 50.17. pg_default_acl
      • 50.18. pg_depend
      • 50.19. pg_description
      • 50.20. pg_enum
      • 50.21. pg_event_trigger
      • 50.22. pg_extension
      • 50.23. pg_foreign_data_wrapper
      • 50.24. pg_foreign_server
      • 50.25. pg_foreign_table
      • 50.26. pg_index
      • 50.27. pg_inherits
      • 50.28. pg_init_privs
      • 50.29. pg_language
      • 50.30. pg_largeobject
      • 50.31. pg_largeobject_metadata
      • 50.32. pg_namespace
      • 50.33. pg_opclass
      • 50.34. pg_operator
      • 50.35. pg_opfamily
      • 50.36. pg_parameter_acl
      • 50.37. pg_partitioned_table
      • 50.38. pg_policy
      • 50.39. pg_proc
      • 50.40. pg_publication
      • 50.41. pg_publication_namespace
      • 50.42. pg_publication_rel
      • 50.43. pg_range
      • 50.44. pg_replication_origin
      • 50.45. pg_rewrite
      • 50.46. pg_seclabel
      • 50.47. pg_sequence
      • 50.48. pg_shdepend
      • 50.49. pg_shdescription
      • 50.50. pg_shseclabel
      • 50.51. pg_statistic
      • 50.52. pg_statistic_ext
      • 50.53. pg_statistic_ext_data
      • 50.54. pg_subscription
      • 50.55. pg_subscription_rel
      • 50.56. pg_tablespace
      • 50.57. pg_transform
      • 50.58. pg_trigger
      • 50.59. pg_ts_config
      • 50.60. pg_ts_config_map
      • 50.61. pg_ts_dict
      • 50.62. pg_ts_parser
      • 50.63. pg_ts_template
      • 50.64. pg_type
      • 50.65. pg_user_mapping
    • Chapter 51. System Views
      • 51.1. Overview
      • 51.2. pg_available_extensions
      • 51.3. pg_available_extension_versions
      • 51.4. pg_backend_memory_contexts
      • 51.5. pg_config
      • 51.6. pg_cursors
      • 51.7. pg_file_settings
      • 51.8. pg_group
      • 51.9. pg_hba_file_rules
      • 51.10. pg_ident_file_mappings
      • 51.11. pg_indexes
      • 51.12. pg_locks
      • 51.13. pg_matviews
      • 51.14. pg_policies
      • 51.15. pg_prepared_statements
      • 51.16. pg_prepared_xacts
      • 51.17. pg_publication_tables
      • 51.18. pg_replication_origin_status
      • 51.19. pg_replication_slots
      • 51.20. pg_roles
      • 51.21. pg_rules
      • 51.22. pg_seclabels
      • 51.23. pg_sequences
      • 51.24. pg_settings
      • 51.25. pg_shadow
      • 51.26. pg_shmem_allocations
      • 51.27. pg_stats
      • 51.28. pg_stats_ext
      • 51.29. pg_stats_ext_exprs
      • 51.30. pg_tables
      • 51.31. pg_timezone_abbrevs
      • 51.32. pg_timezone_names
      • 51.33. pg_user
      • 51.34. pg_user_mappings
      • 51.35. pg_views
    • Chapter 52. Frontend/Backend Protocol
      • 52.1. Overview
      • 52.2. Message Flow
      • 52.3. SASL Authentication
      • 52.4. Streaming Replication Protocol
      • 52.5. Logical Streaming Replication Protocol
      • 52.6. Message Data Types
      • 52.7. Message Formats
      • 52.8. Error and Notice Message Fields
      • 52.9. Logical Replication Message Formats
      • 52.10. Summary of Changes since Protocol 2.0
    • Chapter 53. PostgreSQL Coding Conventions
      • 53.1. Formatting
      • 53.2. Reporting Errors Within the Server
      • 53.3. Error Message Style Guide
      • 53.4. Miscellaneous Coding Conventions
    • Chapter 54. Native Language Support
      • 54.1. For the Translator
      • 54.2. For the Programmer
    • Chapter 55. Writing a Procedural Language Handler
    • Chapter 56. Writing a Foreign Data Wrapper
      • 56.1. Foreign Data Wrapper Functions
      • 56.2. Foreign Data Wrapper Callback Routines
      • 56.3. Foreign Data Wrapper Helper Functions
      • 56.4. Foreign Data Wrapper Query Planning
      • 56.5. Row Locking in Foreign Data Wrappers
    • Chapter 57. Writing a Table Sampling Method
      • 57.1. Sampling Method Support Functions
    • Chapter 58. Writing a Custom Scan Provider
      • 58.1. Creating Custom Scan Paths
      • 58.2. Creating Custom Scan Plans
      • 58.3. Executing Custom Scans
    • Chapter 59. Genetic Query Optimizer
      • 59.1. Query Handling as a Complex Optimization Problem
      • 59.2. Genetic Algorithms
      • 59.3. Genetic Query Optimization (GEQO) in PostgreSQL
      • 59.4. Further Reading
    • Chapter 60. Table Access Method Interface Definition
    • Chapter 61. Index Access Method Interface Definition
      • 61.1. Basic API Structure for Indexes
      • 61.2. Index Access Method Functions
      • 61.3. Index Scanning
      • 61.4. Index Locking Considerations
      • 61.5. Index Uniqueness Checks
      • 61.6. Index Cost Estimation Functions
    • Chapter 62. Generic WAL Records
    • Chapter 63. Custom WAL Resource Managers
    • Chapter 64. B-Tree Indexes
      • 64.1. Introduction
      • 64.2. Behavior of B-Tree Operator Classes
      • 64.3. B-Tree Support Functions
      • 64.4. Implementation
    • Chapter 65. GiST Indexes
      • 65.1. Introduction
      • 65.2. Built-in Operator Classes
      • 65.3. Extensibility
      • 65.4. Implementation
      • 65.5. Examples
    • Chapter 66. SP-GiST Indexes
      • 66.1. Introduction
      • 66.2. Built-in Operator Classes
      • 66.3. Extensibility
      • 66.4. Implementation
      • 66.5. Examples
    • Chapter 67. GIN Indexes
      • 67.1. Introduction
      • 67.2. Built-in Operator Classes
      • 67.3. Extensibility
      • 67.4. Implementation
      • 67.5. GIN Tips and Tricks
      • 67.6. Limitations
      • 67.7. Examples
    • Chapter 68. BRIN Indexes
      • 68.1. Introduction
      • 68.2. Built-in Operator Classes
      • 68.3. Extensibility
    • Chapter 69. Hash Indexes
      • 69.1. Overview
      • 69.2. Implementation
    • Chapter 70. Database Physical Storage
      • 70.1. Database File Layout
      • 70.2. TOAST
      • 70.3. Free Space Map
      • 70.4. Visibility Map
      • 70.5. The Initialization Fork
      • 70.6. Database Page Layout
      • 70.7. Heap-Only Tuples (HOT)
    • Chapter 71. Transaction Processing
      • 71.1. Transactions and Identifiers
      • 71.2. Transactions and Locking
      • 71.3. Subtransactions
      • 71.4. Two-Phase Transactions
    • Chapter 72. System Catalog Declarations and Initial Contents
      • 72.1. System Catalog Declaration Rules
      • 72.2. System Catalog Initial Data
      • 72.3. BKI File Format
      • 72.4. BKI Commands
      • 72.5. Structure of the Bootstrap BKI File
      • 72.6. BKI Example
    • Chapter 73. How the Planner Uses Statistics
      • 73.1. Row Estimation Examples
      • 73.2. Multivariate Statistics Examples
      • 73.3. Planner Statistics and Security
    • Chapter 74. Backup Manifest Format
      • 74.1. Backup Manifest Top-level Object
      • 74.2. Backup Manifest File Object
      • 74.3. Backup Manifest WAL Range Object
  • Part VIII. Appendixes
    • Appendix A. Tantor SE-1C Error Codes
    • Appendix B. Date/Time Support
      • B.1. Date/Time Input Interpretation
      • B.2. Handling of Invalid or Ambiguous Timestamps
      • B.3. Date/Time Key Words
      • B.4. Date/Time Configuration Files
      • B.5. POSIX Time Zone Specifications
      • B.6. History of Units
      • B.7. Julian Dates
    • Appendix C. SQL Key Words
    • Appendix D. SQL Conformance
      • D.1. Supported Features
      • D.2. Unsupported Features
      • D.3. XML Limits and Conformance to SQL/XML
    • Appendix E. Release Notes
      • E.1. Release Notes for Tantor SE-1C 16.10.2
      • E.2. Release Notes for Tantor SE-1C 16.10.1
      • E.3. Release Notes for Tantor SE-1C 16.8.1
      • E.4. Release Notes for Tantor SE-1C 16.8.0
      • E.5. Release Notes for Tantor SE-1C 16.6.2
      • E.6. Release Notes for Tantor SE-1C 16.6.1
      • E.7. Release Notes for Tantor SE-1C 16.6.0
      • E.8. Release Notes for Tantor SE-1C 16.4.0
      • E.9. Release Notes for Tantor SE-1C 16.2.1
      • E.10. Release 16.10
      • E.11. Release 16.9
      • E.12. Release 16.8
      • E.13. Release 16.7
      • E.14. Release 16.6
      • E.15. Release 16.5
      • E.16. Release 16.4
      • E.17. Release 16.3
      • E.18. Release 16.2
      • E.19. Release 16.1
      • E.20. Release 16
      • E.21. Prior Releases
    • Appendix F. Additional Supplied Modules and Extensions
      • F.1. adminpack — pgAdmin support toolpack
      • F.2. amcheck — tools to verify table and index consistency
      • F.3. auth_delay — pause on authentication failure
      • F.4. auto_explain — log execution plans of slow queries
      • F.5. basebackup_to_shell — example “shell” pg_basebackup module
      • F.6. basic_archive — an example WAL archive module
      • F.7. bloom — bloom filter index access method
      • F.8. btree_gin — GIN operator classes with B-tree behavior
      • F.9. btree_gist — GiST operator classes with B-tree behavior
      • F.10. citext — a case-insensitive character string type
      • F.11. spi — Server Programming Interface features/examples
      • F.12. credcheck
      • F.13. cube — a multi-dimensional cube data type
      • F.14. dbcopies_decoding
      • F.15. dblink — connect to other PostgreSQL databases
      • F.16. dict_int — example full-text search dictionary for integers
      • F.17. dict_xsyn — example synonym full-text search dictionary
      • F.18. earthdistance — calculate great-circle distances
      • F.19. fasttrun
      • F.20. file_fdw — access data files in the server’s file system
      • F.21. fulleq
      • F.22. fuzzystrmatch — determine string similarities and distance
      • F.23. hstore — hstore key/value datatype
      • F.24. HypoPG
      • F.25. intagg — integer aggregator and enumerator
      • F.26. intarray — manipulate arrays of integers
      • F.27. isn — data types for international standard numbers (ISBN, EAN, UPC, etc.)
      • F.28. lo — manage large objects
      • F.29. ltree — hierarchical tree-like data type
      • F.30. mchar
      • F.31. old_snapshot — inspect old_snapshot_threshold state
      • F.32. online_analyze
      • F.33. pageinspect — low-level inspection of database pages
      • F.34. page_repair
      • F.35. passwordcheck — verify password strength
      • F.36. pgAudit
      • F.37. pgAudit Log to File
      • F.38. pg_buffercache — inspect Tantor SE-1C buffer cache state
      • F.39. pg_cron
      • F.40. pgcrypto — cryptographic functions
      • F.41. pg_freespacemap — examine the free space map
      • F.42. pg_hint_plan
      • F.43. pg_prewarm — preload relation data into buffer caches
      • F.44. pg_repack
      • F.45. pgrowlocks — show a table’s row locking information
      • F.46. pg_stat_kcache
      • F.47. pg_stat_statements — track statistics of SQL planning and execution
      • F.48. pgstattuple — obtain tuple-level statistics
      • F.49. pg_store_plans
      • F.50. pg_surgery — perform low-level surgery on relation data
      • F.51. pg_trace
      • F.52. pg_trgm — support for similarity of text using trigram matching
      • F.53. pg_uuidv7
      • F.54. pg_visibility — visibility map information and utilities
      • F.55. pg_wait_sampling
      • F.56. pg_walinspect — low-level WAL inspection
      • F.57. plantuner
      • F.58. postgres_fdw — access data stored in external Tantor SE-1C servers
      • F.59. seg — a datatype for line segments or floating point intervals
      • F.60. sepgsql — SELinux-, label-based mandatory access control (MAC) security module
      • F.61. sslinfo — obtain client SSL information
      • F.62. tablefunc — functions that return tables (crosstab and others)
      • F.63. tcn — a trigger function to notify listeners of changes to table content
      • F.64. test_decoding — SQL-based test/example module for WAL logical decoding
      • F.65. transp_anon
      • F.66. tsm_system_rows — the SYSTEM_ROWS sampling method for TABLESAMPLE
      • F.67. tsm_system_time — the SYSTEM_TIME sampling method for TABLESAMPLE
      • F.68. unaccent — a text search dictionary which removes diacritics
      • F.69. uuid-ossp — a UUID generator
      • F.70. wal2json
      • F.71. xml2 — XPath querying and XSLT functionality
    • Appendix G. Additional Supplied Programs
      • G.1. Client Applications
      • G.2. Server Applications
    • Appendix H. Additional External Modules
      • H.1. ldap2pg
      • H.2. MySQL Foreign Data Wrapper
      • H.3. Oracle FDW
      • H.4. pg_cluster
      • H.5. pg_configurator
      • H.6. pg_timetable
      • H.7. pgbouncer
      • H.8. TDS Foreign data wrapper
    • Appendix I. External Projects
      • I.1. Client Interfaces
      • I.2. Administration Tools
      • I.3. Procedural Languages
      • I.4. Extensions
    • Appendix J. Tantor SE-1C Limits
    • Appendix K. Acronyms
    • Appendix L. Glossary
    • Appendix M. Color Support
      • M.1. When Color is Used
      • M.2. Configuring the Colors
    • Appendix N. Obsolete or Renamed Features
      • N.1. recovery.conf file merged into postgresql.conf
      • N.2. Default Roles Renamed to Predefined Roles
      • N.3. pg_xlogdump renamed to pg_waldump
      • N.4. pg_resetxlog renamed to pg_resetwal
      • N.5. pg_receivexlog renamed to pg_receivewal
  • Bibliography
  • Index

35.16. Packaging Related Objects into an Extension

35.16. Packaging Related Objects into an Extension#

35.16. Packaging Related Objects into an Extension
35.16. Packaging Related Objects into an Extension
Prev UpChapter 35. Extending SQLHome Next

35.16. Packaging Related Objects into an Extension #

35.16.1. Extension Files
35.16.2. Extension Relocatability
35.16.3. Extension Configuration Tables
35.16.4. Extension Updates
35.16.5. Installing Extensions Using Update Scripts
35.16.6. Security Considerations for Extensions
35.16.7. Extension Example

A useful extension to Tantor SE-1C typically includes multiple SQL objects; for example, a new data type will require new functions, new operators, and probably new index operator classes. It is helpful to collect all these objects into a single package to simplify database management. Tantor SE-1C calls such a package an extension. To define an extension, you need at least a script file that contains the SQL commands to create the extension's objects, and a control file that specifies a few basic properties of the extension itself. If the extension includes C code, there will typically also be a shared library file into which the C code has been built. Once you have these files, a simple CREATE EXTENSION command loads the objects into your database.

The main advantage of using an extension, rather than just running the SQL script to load a bunch of “loose” objects into your database, is that Tantor SE-1C will then understand that the objects of the extension go together. You can drop all the objects with a single DROP EXTENSION command (no need to maintain a separate “uninstall” script). Even more useful, pg_dump knows that it should not dump the individual member objects of the extension — it will just include a CREATE EXTENSION command in dumps, instead. This vastly simplifies migration to a new version of the extension that might contain more or different objects than the old version. Note however that you must have the extension's control, script, and other files available when loading such a dump into a new database.

Tantor SE-1C will not let you drop an individual object contained in an extension, except by dropping the whole extension. Also, while you can change the definition of an extension member object (for example, via CREATE OR REPLACE FUNCTION for a function), bear in mind that the modified definition will not be dumped by pg_dump. Such a change is usually only sensible if you concurrently make the same change in the extension's script file. (But there are special provisions for tables containing configuration data; see Section 35.16.3.) In production situations, it's generally better to create an extension update script to perform changes to extension member objects.

The extension script may set privileges on objects that are part of the extension, using GRANT and REVOKE statements. The final set of privileges for each object (if any are set) will be stored in the pg_init_privs system catalog. When pg_dump is used, the CREATE EXTENSION command will be included in the dump, followed by the set of GRANT and REVOKE statements necessary to set the privileges on the objects to what they were at the time the dump was taken.

Tantor SE-1C does not currently support extension scripts issuing CREATE POLICY or SECURITY LABEL statements. These are expected to be set after the extension has been created. All RLS policies and security labels on extension objects will be included in dumps created by pg_dump.

The extension mechanism also has provisions for packaging modification scripts that adjust the definitions of the SQL objects contained in an extension. For example, if version 1.1 of an extension adds one function and changes the body of another function compared to 1.0, the extension author can provide an update script that makes just those two changes. The ALTER EXTENSION UPDATE command can then be used to apply these changes and track which version of the extension is actually installed in a given database.

The kinds of SQL objects that can be members of an extension are shown in the description of ALTER EXTENSION. Notably, objects that are database-cluster-wide, such as databases, roles, and tablespaces, cannot be extension members since an extension is only known within one database. (Although an extension script is not prohibited from creating such objects, if it does so they will not be tracked as part of the extension.) Also notice that while a table can be a member of an extension, its subsidiary objects such as indexes are not directly considered members of the extension. Another important point is that schemas can belong to extensions, but not vice versa: an extension as such has an unqualified name and does not exist “within” any schema. The extension's member objects, however, will belong to schemas whenever appropriate for their object types. It may or may not be appropriate for an extension to own the schema(s) its member objects are within.

If an extension's script creates any temporary objects (such as temp tables), those objects are treated as extension members for the remainder of the current session, but are automatically dropped at session end, as any temporary object would be. This is an exception to the rule that extension member objects cannot be dropped without dropping the whole extension.

35.16.1. Extension Files #

The CREATE EXTENSION command relies on a control file for each extension, which must be named the same as the extension with a suffix of .control, and must be placed in the installation's SHAREDIR/extension directory. There must also be at least one SQL script file, which follows the naming pattern extension--version.sql (for example, foo--1.0.sql for version 1.0 of extension foo). By default, the script file(s) are also placed in the SHAREDIR/extension directory; but the control file can specify a different directory for the script file(s).

The file format for an extension control file is the same as for the postgresql.conf file, namely a list of parameter_name = value assignments, one per line. Blank lines and comments introduced by # are allowed. Be sure to quote any value that is not a single word or number.

A control file can set the following parameters:

directory (string) #

The directory containing the extension's SQL script file(s). Unless an absolute path is given, the name is relative to the installation's SHAREDIR directory. The default behavior is equivalent to specifying directory = 'extension'.

default_version (string) #

The default version of the extension (the one that will be installed if no version is specified in CREATE EXTENSION). Although this can be omitted, that will result in CREATE EXTENSION failing if no VERSION option appears, so you generally don't want to do that.

comment (string) #

A comment (any string) about the extension. The comment is applied when initially creating an extension, but not during extension updates (since that might override user-added comments). Alternatively, the extension's comment can be set by writing a COMMENT command in the script file.

encoding (string) #

The character set encoding used by the script file(s). This should be specified if the script files contain any non-ASCII characters. Otherwise the files will be assumed to be in the database encoding.

module_pathname (string) #

The value of this parameter will be substituted for each occurrence of MODULE_PATHNAME in the script file(s). If it is not set, no substitution is made. Typically, this is set to $libdir/shared_library_name and then MODULE_PATHNAME is used in CREATE FUNCTION commands for C-language functions, so that the script files do not need to hard-wire the name of the shared library.

requires (string) #

A list of names of extensions that this extension depends on, for example requires = 'foo, bar'. Those extensions must be installed before this one can be installed.

no_relocate (string) #

A list of names of extensions that this extension depends on that should be barred from changing their schemas via ALTER EXTENSION ... SET SCHEMA. This is needed if this extension's script references the name of a required extension's schema (using the @extschema:name@ syntax) in a way that cannot track renames.

superuser (boolean) #

If this parameter is true (which is the default), only superusers can create the extension or update it to a new version (but see also trusted, below). If it is set to false, just the privileges required to execute the commands in the installation or update script are required. This should normally be set to true if any of the script commands require superuser privileges. (Such commands would fail anyway, but it's more user-friendly to give the error up front.)

trusted (boolean) #

This parameter, if set to true (which is not the default), allows some non-superusers to install an extension that has superuser set to true. Specifically, installation will be permitted for anyone who has CREATE privilege on the current database. When the user executing CREATE EXTENSION is not a superuser but is allowed to install by virtue of this parameter, then the installation or update script is run as the bootstrap superuser, not as the calling user. This parameter is irrelevant if superuser is false. Generally, this should not be set true for extensions that could allow access to otherwise-superuser-only abilities, such as file system access. Also, marking an extension trusted requires significant extra effort to write the extension's installation and update script(s) securely; see Section 35.16.6.

relocatable (boolean) #

An extension is relocatable if it is possible to move its contained objects into a different schema after initial creation of the extension. The default is false, i.e., the extension is not relocatable. See Section 35.16.2 for more information.

schema (string) #

This parameter can only be set for non-relocatable extensions. It forces the extension to be loaded into exactly the named schema and not any other. The schema parameter is consulted only when initially creating an extension, not during extension updates. See Section 35.16.2 for more information.

In addition to the primary control file extension.control, an extension can have secondary control files named in the style extension--version.control. If supplied, these must be located in the script file directory. Secondary control files follow the same format as the primary control file. Any parameters set in a secondary control file override the primary control file when installing or updating to that version of the extension. However, the parameters directory and default_version cannot be set in a secondary control file.

An extension's SQL script files can contain any SQL commands, except for transaction control commands (BEGIN, COMMIT, etc.) and commands that cannot be executed inside a transaction block (such as VACUUM). This is because the script files are implicitly executed within a transaction block.

An extension's SQL script files can also contain lines beginning with \echo, which will be ignored (treated as comments) by the extension mechanism. This provision is commonly used to throw an error if the script file is fed to psql rather than being loaded via CREATE EXTENSION (see example script in Section 35.16.7). Without that, users might accidentally load the extension's contents as “loose” objects rather than as an extension, a state of affairs that's a bit tedious to recover from.

If the extension script contains the string @extowner@, that string is replaced with the (suitably quoted) name of the user calling CREATE EXTENSION or ALTER EXTENSION. Typically this feature is used by extensions that are marked trusted to assign ownership of selected objects to the calling user rather than the bootstrap superuser. (One should be careful about doing so, however. For example, assigning ownership of a C-language function to a non-superuser would create a privilege escalation path for that user.)

While the script files can contain any characters allowed by the specified encoding, control files should contain only plain ASCII, because there is no way for Tantor SE-1C to know what encoding a control file is in. In practice this is only an issue if you want to use non-ASCII characters in the extension's comment. Recommended practice in that case is to not use the control file comment parameter, but instead use COMMENT ON EXTENSION within a script file to set the comment.

35.16.2. Extension Relocatability #

Users often wish to load the objects contained in an extension into a different schema than the extension's author had in mind. There are three supported levels of relocatability:

  • A fully relocatable extension can be moved into another schema at any time, even after it's been loaded into a database. This is done with the ALTER EXTENSION SET SCHEMA command, which automatically renames all the member objects into the new schema. Normally, this is only possible if the extension contains no internal assumptions about what schema any of its objects are in. Also, the extension's objects must all be in one schema to begin with (ignoring objects that do not belong to any schema, such as procedural languages). Mark a fully relocatable extension by setting relocatable = true in its control file.

  • An extension might be relocatable during installation but not afterwards. This is typically the case if the extension's script file needs to reference the target schema explicitly, for example in setting search_path properties for SQL functions. For such an extension, set relocatable = false in its control file, and use @extschema@ to refer to the target schema in the script file. All occurrences of this string will be replaced by the actual target schema's name (double-quoted if necessary) before the script is executed. The user can set the target schema using the SCHEMA option of CREATE EXTENSION.

  • If the extension does not support relocation at all, set relocatable = false in its control file, and also set schema to the name of the intended target schema. This will prevent use of the SCHEMA option of CREATE EXTENSION, unless it specifies the same schema named in the control file. This choice is typically necessary if the extension contains internal assumptions about its schema name that can't be replaced by uses of @extschema@. The @extschema@ substitution mechanism is available in this case too, although it is of limited use since the schema name is determined by the control file.

In all cases, the script file will be executed with search_path initially set to point to the target schema; that is, CREATE EXTENSION does the equivalent of this:

SET LOCAL search_path TO @extschema@, pg_temp;

This allows the objects created by the script file to go into the target schema. The script file can change search_path if it wishes, but that is generally undesirable. search_path is restored to its previous setting upon completion of CREATE EXTENSION.

The target schema is determined by the schema parameter in the control file if that is given, otherwise by the SCHEMA option of CREATE EXTENSION if that is given, otherwise the current default object creation schema (the first one in the caller's search_path). When the control file schema parameter is used, the target schema will be created if it doesn't already exist, but in the other two cases it must already exist.

If any prerequisite extensions are listed in requires in the control file, their target schemas are added to the initial setting of search_path, following the new extension's target schema. This allows their objects to be visible to the new extension's script file.

For security, pg_temp is automatically appended to the end of search_path in all cases.

Although a non-relocatable extension can contain objects spread across multiple schemas, it is usually desirable to place all the objects meant for external use into a single schema, which is considered the extension's target schema. Such an arrangement works conveniently with the default setting of search_path during creation of dependent extensions.

If an extension references objects belonging to another extension, it is recommended to schema-qualify those references. To do that, write @extschema:name@ in the extension's script file, where name is the name of the other extension (which must be listed in this extension's requires list). This string will be replaced by the name (double-quoted if necessary) of that extension's target schema. Although this notation avoids the need to make hard-wired assumptions about schema names in the extension's script file, its use may embed the other extension's schema name into the installed objects of this extension. (Typically, that happens when @extschema:name@ is used inside a string literal, such as a function body or a search_path setting. In other cases, the object reference is reduced to an OID during parsing and does not require subsequent lookups.) If the other extension's schema name is so embedded, you should prevent the other extension from being relocated after yours is installed, by adding the name of the other extension to this one's no_relocate list.

35.16.3. Extension Configuration Tables #

Some extensions include configuration tables, which contain data that might be added or changed by the user after installation of the extension. Ordinarily, if a table is part of an extension, neither the table's definition nor its content will be dumped by pg_dump. But that behavior is undesirable for a configuration table; any data changes made by the user need to be included in dumps, or the extension will behave differently after a dump and restore.

To solve this problem, an extension's script file can mark a table or a sequence it has created as a configuration relation, which will cause pg_dump to include the table's or the sequence's contents (not its definition) in dumps. To do that, call the function pg_extension_config_dump(regclass, text) after creating the table or the sequence, for example

CREATE TABLE my_config (key text, value text);
CREATE SEQUENCE my_config_seq;

SELECT pg_catalog.pg_extension_config_dump('my_config', '');
SELECT pg_catalog.pg_extension_config_dump('my_config_seq', '');

Any number of tables or sequences can be marked this way. Sequences associated with serial or bigserial columns can be marked as well.

When the second argument of pg_extension_config_dump is an empty string, the entire contents of the table are dumped by pg_dump. This is usually only correct if the table is initially empty as created by the extension script. If there is a mixture of initial data and user-provided data in the table, the second argument of pg_extension_config_dump provides a WHERE condition that selects the data to be dumped. For example, you might do

CREATE TABLE my_config (key text, value text, standard_entry boolean);

SELECT pg_catalog.pg_extension_config_dump('my_config', 'WHERE NOT standard_entry');

and then make sure that standard_entry is true only in the rows created by the extension's script.

For sequences, the second argument of pg_extension_config_dump has no effect.

More complicated situations, such as initially-provided rows that might be modified by users, can be handled by creating triggers on the configuration table to ensure that modified rows are marked correctly.

You can alter the filter condition associated with a configuration table by calling pg_extension_config_dump again. (This would typically be useful in an extension update script.) The only way to mark a table as no longer a configuration table is to dissociate it from the extension with ALTER EXTENSION ... DROP TABLE.

Note that foreign key relationships between these tables will dictate the order in which the tables are dumped out by pg_dump. Specifically, pg_dump will attempt to dump the referenced-by table before the referencing table. As the foreign key relationships are set up at CREATE EXTENSION time (prior to data being loaded into the tables) circular dependencies are not supported. When circular dependencies exist, the data will still be dumped out but the dump will not be able to be restored directly and user intervention will be required.

Sequences associated with serial or bigserial columns need to be directly marked to dump their state. Marking their parent relation is not enough for this purpose.

35.16.4. Extension Updates #

One advantage of the extension mechanism is that it provides convenient ways to manage updates to the SQL commands that define an extension's objects. This is done by associating a version name or number with each released version of the extension's installation script. In addition, if you want users to be able to update their databases dynamically from one version to the next, you should provide update scripts that make the necessary changes to go from one version to the next. Update scripts have names following the pattern extension--old_version--target_version.sql (for example, foo--1.0--1.1.sql contains the commands to modify version 1.0 of extension foo into version 1.1).

Given that a suitable update script is available, the command ALTER EXTENSION UPDATE will update an installed extension to the specified new version. The update script is run in the same environment that CREATE EXTENSION provides for installation scripts: in particular, search_path is set up in the same way, and any new objects created by the script are automatically added to the extension. Also, if the script chooses to drop extension member objects, they are automatically dissociated from the extension.

If an extension has secondary control files, the control parameters that are used for an update script are those associated with the script's target (new) version.

ALTER EXTENSION is able to execute sequences of update script files to achieve a requested update. For example, if only foo--1.0--1.1.sql and foo--1.1--2.0.sql are available, ALTER EXTENSION will apply them in sequence if an update to version 2.0 is requested when 1.0 is currently installed.

Tantor SE-1C doesn't assume anything about the properties of version names: for example, it does not know whether 1.1 follows 1.0. It just matches up the available version names and follows the path that requires applying the fewest update scripts. (A version name can actually be any string that doesn't contain -- or leading or trailing -.)

Sometimes it is useful to provide “downgrade” scripts, for example foo--1.1--1.0.sql to allow reverting the changes associated with version 1.1. If you do that, be careful of the possibility that a downgrade script might unexpectedly get applied because it yields a shorter path. The risky case is where there is a “fast path” update script that jumps ahead several versions as well as a downgrade script to the fast path's start point. It might take fewer steps to apply the downgrade and then the fast path than to move ahead one version at a time. If the downgrade script drops any irreplaceable objects, this will yield undesirable results.

To check for unexpected update paths, use this command:

SELECT * FROM pg_extension_update_paths('extension_name');

This shows each pair of distinct known version names for the specified extension, together with the update path sequence that would be taken to get from the source version to the target version, or NULL if there is no available update path. The path is shown in textual form with -- separators. You can use regexp_split_to_array(path,'--') if you prefer an array format.

35.16.5. Installing Extensions Using Update Scripts #

An extension that has been around for awhile will probably exist in several versions, for which the author will need to write update scripts. For example, if you have released a foo extension in versions 1.0, 1.1, and 1.2, there should be update scripts foo--1.0--1.1.sql and foo--1.1--1.2.sql. Before PostgreSQL 10, it was necessary to also create new script files foo--1.1.sql and foo--1.2.sql that directly build the newer extension versions, or else the newer versions could not be installed directly, only by installing 1.0 and then updating. That was tedious and duplicative, but now it's unnecessary, because CREATE EXTENSION can follow update chains automatically. For example, if only the script files foo--1.0.sql, foo--1.0--1.1.sql, and foo--1.1--1.2.sql are available then a request to install version 1.2 is honored by running those three scripts in sequence. The processing is the same as if you'd first installed 1.0 and then updated to 1.2. (As with ALTER EXTENSION UPDATE, if multiple pathways are available then the shortest is preferred.) Arranging an extension's script files in this style can reduce the amount of maintenance effort needed to produce small updates.

If you use secondary (version-specific) control files with an extension maintained in this style, keep in mind that each version needs a control file even if it has no stand-alone installation script, as that control file will determine how the implicit update to that version is performed. For example, if foo--1.0.control specifies requires = 'bar' but foo's other control files do not, the extension's dependency on bar will be dropped when updating from 1.0 to another version.

35.16.6. Security Considerations for Extensions #

Widely-distributed extensions should assume little about the database they occupy. Therefore, it's appropriate to write functions provided by an extension in a secure style that cannot be compromised by search-path-based attacks.

An extension that has the superuser property set to true must also consider security hazards for the actions taken within its installation and update scripts. It is not terribly difficult for a malicious user to create trojan-horse objects that will compromise later execution of a carelessly-written extension script, allowing that user to acquire superuser privileges.

If an extension is marked trusted, then its installation schema can be selected by the installing user, who might intentionally use an insecure schema in hopes of gaining superuser privileges. Therefore, a trusted extension is extremely exposed from a security standpoint, and all its script commands must be carefully examined to ensure that no compromise is possible.

Advice about writing functions securely is provided in Section 35.16.6.1 below, and advice about writing installation scripts securely is provided in Section 35.16.6.2.

35.16.6.1. Security Considerations for Extension Functions #

SQL-language and PL-language functions provided by extensions are at risk of search-path-based attacks when they are executed, since parsing of these functions occurs at execution time not creation time.

The CREATE FUNCTION reference page contains advice about writing SECURITY DEFINER functions safely. It's good practice to apply those techniques for any function provided by an extension, since the function might be called by a high-privilege user.

If you cannot set the search_path to contain only secure schemas, assume that each unqualified name could resolve to an object that a malicious user has defined. Beware of constructs that depend on search_path implicitly; for example, IN and CASE expression WHEN always select an operator using the search path. In their place, use OPERATOR(schema.=) ANY and CASE WHEN expression.

A general-purpose extension usually should not assume that it's been installed into a secure schema, which means that even schema-qualified references to its own objects are not entirely risk-free. For example, if the extension has defined a function myschema.myfunc(bigint) then a call such as myschema.myfunc(42) could be captured by a hostile function myschema.myfunc(integer). Be careful that the data types of function and operator parameters exactly match the declared argument types, using explicit casts where necessary.

35.16.6.2. Security Considerations for Extension Scripts #

An extension installation or update script should be written to guard against search-path-based attacks occurring when the script executes. If an object reference in the script can be made to resolve to some other object than the script author intended, then a compromise might occur immediately, or later when the mis-defined extension object is used.

DDL commands such as CREATE FUNCTION and CREATE OPERATOR CLASS are generally secure, but beware of any command having a general-purpose expression as a component. For example, CREATE VIEW needs to be vetted, as does a DEFAULT expression in CREATE FUNCTION.

Sometimes an extension script might need to execute general-purpose SQL, for example to make catalog adjustments that aren't possible via DDL. Be careful to execute such commands with a secure search_path; do not trust the path provided by CREATE/ALTER EXTENSION to be secure. Best practice is to temporarily set search_path to pg_catalog, pg_temp and insert references to the extension's installation schema explicitly where needed. (This practice might also be helpful for creating views.) Examples can be found in the contrib modules in the Tantor SE-1C source code distribution.

Cross-extension references are extremely difficult to make fully secure, partially because of uncertainty about which schema the other extension is in. The hazards are reduced if both extensions are installed in the same schema, because then a hostile object cannot be placed ahead of the referenced extension in the installation-time search_path. However, no mechanism currently exists to require that. For now, best practice is to not mark an extension trusted if it depends on another one, unless that other one is always installed in pg_catalog.

35.16.7. Extension Example #

Here is a complete example of an SQL-only extension, a two-element composite type that can store any type of value in its slots, which are named “k” and “v”. Non-text values are automatically coerced to text for storage.

The script file pair--1.0.sql looks like this:

-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pair" to load this file. \quit

CREATE TYPE pair AS ( k text, v text );

CREATE FUNCTION pair(text, text)
RETURNS pair LANGUAGE SQL AS 'SELECT ROW($1, $2)::@extschema@.pair;';

CREATE OPERATOR ~> (LEFTARG = text, RIGHTARG = text, FUNCTION = pair);

-- "SET search_path" is easy to get right, but qualified names perform better.
CREATE FUNCTION lower(pair)
RETURNS pair LANGUAGE SQL
AS 'SELECT ROW(lower($1.k), lower($1.v))::@extschema@.pair;'
SET search_path = pg_temp;

CREATE FUNCTION pair_concat(pair, pair)
RETURNS pair LANGUAGE SQL
AS 'SELECT ROW($1.k OPERATOR(pg_catalog.||) $2.k,
               $1.v OPERATOR(pg_catalog.||) $2.v)::@extschema@.pair;';

The control file pair.control looks like this:

# pair extension
comment = 'A key/value pair data type'
default_version = '1.0'
# cannot be relocatable because of use of @extschema@
relocatable = false

While you hardly need a makefile to install these two files into the correct directory, you could use a Makefile containing this:

EXTENSION = pair
DATA = pair--1.0.sql

PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)

This makefile relies on PGXS, which is described in Section 35.17. The command make install will install the control and script files into the correct directory as reported by pg_config.

Once the files are installed, use the CREATE EXTENSION command to load the objects into any particular database.


Prev Up Next
35.15. Interfacing Extensions to Indexes Home 35.17. Extension Building Infrastructure

previous

35.15. Interfacing Extensions to Indexes

next

35.17. Extension Building Infrastructure

By Tantor Labs

© Copyright 2025, Tantor Labs.

Commercial use is possible only with written permission from the company LLC “Tantor Labs”
© LLC "Tantor Labs"
  • Technical Support Policy
  • Cookie Processing Policy
  • Website User Agreement
Products
  • Tantor DBMS
  • Tantor Platform
  • Documentation
Contacts
  • +7 495 369-48-16
  • info@tantorlabs.ru
16.10.2 - de035b67 - 2025-11-01 09:05:05