- About MogDB
- MogDB Introduction
- Comparison Between MogDB and openGauss
- MogDB Release Notes
- High Availability and Performance
- Open Source Components
- Usage Limitations
- Terms of Use
- Quick Start
- Installation Guide
- Container Installation
- Simplified Installation Process
- Standard Installation
- Manual Installation
- Administrator Guide
- Routine Maintenance
- Starting and Stopping MogDB
- Using the gsql Client for Connection
- Routine Maintenance
- Checking OS Parameters
- Checking MogDB Health Status
- Checking Database Performance
- Checking and Deleting Logs
- Checking Time Consistency
- Checking The Number of Application Connections
- Routinely Maintaining Tables
- Routinely Recreating an Index
- Data Security Maintenance Suggestions
- Log Reference
- Primary and Standby Management
- MOT Engine
- Introducing MOT
- Using MOT
- Concepts of MOT
- Appendix
- Column-store Tables Management
- Backup and Restoration
- Importing and Exporting Data
- Importing Data
- Exporting Data
- Upgrade Guide
- Common Fault Locating Cases
- Core Fault Locating
- When the TPC-C is running and a disk to be injected is full, the TPC-C stops responding
- Standby Node in the Need Repair (WAL) State
- Insufficient Memory
- Service Startup Failure
- "Error:No space left on device" Is Displayed
- After You Run the du Command to Query Data File Size In the XFS File System, the Query Result Is Greater than the Actual File Size
- File Is Damaged in the XFS File System
- Primary Node Is Hung in Demoting During a Switchover
- Disk Space Usage Reaches the Threshold and the Database Becomes Read-only
- Slow Response to a Query Statement
- Analyzing the Status of a Query Statement
- Forcibly Terminating a Session
- Analyzing Whether a Query Statement Is Blocked
- Low Query Efficiency
- "Lock wait timeout" Is Displayed When a User Executes an SQL Statement
- Table Size Does not Change After VACUUM FULL Is Executed on the Table
- An Error Is Reported When the Table Partition Is Modified
- Different Data Is Displayed for the Same Table Queried By Multiple Users
- When a User Specifies Only an Index Name to Modify the Index, A Message Indicating That the Index Does Not Exist Is Displayed
- Reindexing Fails
- An Error Occurs During Integer Conversion
- "too many clients already" Is Reported or Threads Failed To Be Created in High Concurrency Scenarios
- B-tree Index Faults
- Routine Maintenance
- Security Guide
- Database Security Management
- Performance Tuning
- System Optimization
- SQL Optimization
- WDR Snapshot Schema
- TPCC Performance Tuning Guide
- Developer Guide
- Application Development Guide
- Development Specifications
- Development Based on JDBC
- Overview
- JDBC Package, Driver Class, and Environment Class
- Development Process
- Loading the Driver
- Connecting to a Database
- Connecting to the Database (Using SSL)
- Running SQL Statements
- Processing Data in a Result Set
- Closing a Connection
- Example: Common Operations
- Example: Retrying SQL Queries for Applications
- Example: Importing and Exporting Data Through Local Files
- Example 2: Migrating Data from a MY Database to MogDB
- Example: Logic Replication Code
- JDBC API Reference
- java.sql.Connection
- java.sql.CallableStatement
- java.sql.DatabaseMetaData
- java.sql.Driver
- java.sql.PreparedStatement
- java.sql.ResultSet
- java.sql.ResultSetMetaData
- java.sql.Statement
- javax.sql.ConnectionPoolDataSource
- javax.sql.DataSource
- javax.sql.PooledConnection
- javax.naming.Context
- javax.naming.spi.InitialContextFactory
- CopyManager
- Development Based on ODBC
- Development Based on libpq
- Development Based on libpq
- libpq API Reference
- Database Connection Control Functions
- Database Statement Execution Functions
- Functions for Asynchronous Command Processing
- Functions for Canceling Queries in Progress
- Example
- Connection Characters
- Commissioning
- Appendices
- Stored Procedure
- User Defined Functions
- Autonomous Transaction
- Logical Replication
- Logical Decoding
- Foreign Data Wrapper
- Materialized View
- Materialized View Overview
- Full Materialized View
- Incremental Materialized View
- AI Features
- Overview
- Predictor: AI Query Time Forecasting
- X-Tuner: Parameter Optimization and Diagnosis
- SQLdiag: Slow SQL Discovery
- A-Detection: Status Monitoring
- Index-advisor: Index Recommendation
- DeepSQL
- Application Development Guide
- Reference Guide
- System Catalogs and System Views
- Overview of System Catalogs and System Views
- System Catalogs
- GS_AUDITING_POLICY
- GS_AUDITING_POLICY_ACCESS
- GS_AUDITING_POLICY_FILTERS
- GS_AUDITING_POLICY_PRIVILEGES
- GS_CLIENT_GLOBAL_KEYS
- GS_CLIENT_GLOBAL_KEYS_ARGS
- GS_COLUMN_KEYS
- GS_COLUMN_KEYS_ARGS
- GS_ENCRYPTED_COLUMNS
- GS_MASKING_POLICY
- GS_MASKING_POLICY_ACTIONS
- GS_MASKING_POLICY_FILTERS
- GS_MATVIEW
- GS_MATVIEW_DEPENDENCY
- GS_OPT_MODEL
- GS_POLICY_LABEL
- GS_WLM_INSTANCE_HISTORY
- GS_WLM_OPERATOR_INFO
- GS_WLM_PLAN_ENCODING_TABLE
- GS_WLM_PLAN_OPERATOR_INFO
- GS_WLM_USER_RESOURCE_HISTORY
- PG_AGGREGATE
- PG_AM
- PG_AMOP
- PG_AMPROC
- PG_APP_WORKLOADGROUP_MAPPING
- PG_ATTRDEF
- PG_ATTRIBUTE
- PG_AUTHID
- PG_AUTH_HISTORY
- PG_AUTH_MEMBERS
- PG_CAST
- PG_CLASS
- PG_COLLATION
- PG_CONSTRAINT
- PG_CONVERSION
- PG_DATABASE
- PG_DB_ROLE_SETTING
- PG_DEFAULT_ACL
- PG_DEPEND
- PG_DESCRIPTION
- PG_DIRECTORY
- PG_ENUM
- PG_EXTENSION
- PG_EXTENSION_DATA_SOURCE
- PG_FOREIGN_DATA_WRAPPER
- PG_FOREIGN_SERVER
- PG_FOREIGN_TABLE
- PG_INDEX
- PG_INHERITS
- PG_JOB
- PG_JOB_PROC
- PG_LANGUAGE
- PG_LARGEOBJECT
- PG_LARGEOBJECT_METADATA
- PG_NAMESPACE
- PG_OBJECT
- PG_OPCLASS
- PG_OPERATOR
- PG_OPFAMILY
- PG_PARTITION
- PG_PLTEMPLATE
- PG_PROC
- PG_RANGE
- PG_RESOURCE_POOL
- PG_REWRITE
- PG_RLSPOLICY
- PG_SECLABEL
- PG_SHDEPEND
- PG_SHDESCRIPTION
- PG_SHSECLABEL
- PG_STATISTIC
- PG_STATISTIC_EXT
- PG_SYNONYM
- PG_TABLESPACE
- PG_TRIGGER
- PG_TS_CONFIG
- PG_TS_CONFIG_MAP
- PG_TS_DICT
- PG_TS_PARSER
- PG_TS_TEMPLATE
- PG_TYPE
- PG_USER_MAPPING
- PG_USER_STATUS
- PG_WORKLOAD_GROUP
- PLAN_TABLE_DATA
- STATEMENT_HISTORY
- System Views
- GS_AUDITING
- GS_AUDITING_ACCESS
- GS_AUDITING_PRIVILEGE
- GS_CLUSTER_RESOURCE_INFO
- GS_INSTANCE_TIME
- GS_LABELS
- GS_MASKING
- GS_MATVIEWS
- GS_SESSION_MEMORY
- GS_SESSION_CPU_STATISTICS
- GS_SESSION_MEMORY_CONTEXT
- GS_SESSION_MEMORY_DETAIL
- GS_SESSION_MEMORY_STATISTICS
- GS_SQL_COUNT
- GS_WLM_CGROUP_INFO
- GS_WLM_PLAN_OPERATOR_HISTORY
- GS_WLM_REBUILD_USER_RESOURCE_POOL
- GS_WLM_RESOURCE_POOL
- GS_WLM_USER_INFO
- GS_STAT_SESSION_CU
- GS_TOTAL_MEMORY_DETAIL
- MPP_TABLES
- PG_AVAILABLE_EXTENSION_VERSIONS
- PG_AVAILABLE_EXTENSIONS
- PG_COMM_DELAY
- PG_COMM_RECV_STREAM
- PG_COMM_SEND_STREAM
- PG_COMM_STATUS
- PG_CONTROL_GROUP_CONFIG
- PG_CURSORS
- PG_EXT_STATS
- PG_GET_INVALID_BACKENDS
- PG_GET_SENDERS_CATCHUP_TIME
- PG_GROUP
- PG_GTT_RELSTATS
- PG_GTT_STATS
- PG_GTT_ATTACHED_PIDS
- PG_INDEXES
- PG_LOCKS
- PG_NODE_ENV
- PG_OS_THREADS
- PG_PREPARED_STATEMENTS
- PG_PREPARED_XACTS
- PG_REPLICATION_SLOTS
- PG_RLSPOLICIES
- PG_ROLES
- PG_RULES
- PG_SECLABELS
- PG_SETTINGS
- PG_SHADOW
- PG_STATS
- PG_STAT_ACTIVITY
- PG_STAT_ALL_INDEXES
- PG_STAT_ALL_TABLES
- PG_STAT_BAD_BLOCK
- PG_STAT_BGWRITER
- PG_STAT_DATABASE
- PG_STAT_DATABASE_CONFLICTS
- PG_STAT_USER_FUNCTIONS
- PG_STAT_USER_INDEXES
- PG_STAT_USER_TABLES
- PG_STAT_REPLICATION
- PG_STAT_SYS_INDEXES
- PG_STAT_SYS_TABLES
- PG_STAT_XACT_ALL_TABLES
- PG_STAT_XACT_SYS_TABLES
- PG_STAT_XACT_USER_FUNCTIONS
- PG_STAT_XACT_USER_TABLES
- PG_STATIO_ALL_INDEXES
- PG_STATIO_ALL_SEQUENCES
- PG_STATIO_ALL_TABLES
- PG_STATIO_SYS_INDEXES
- PG_STATIO_SYS_SEQUENCES
- PG_STATIO_SYS_TABLES
- PG_STATIO_USER_INDEXES
- PG_STATIO_USER_SEQUENCES
- PG_STATIO_USER_TABLES
- PG_TABLES
- PG_TDE_INFO
- PG_THREAD_WAIT_STATUS
- PG_TIMEZONE_ABBREVS
- PG_TIMEZONE_NAMES
- PG_TOTAL_MEMORY_DETAIL
- PG_TOTAL_USER_RESOURCE_INFO
- PG_TOTAL_USER_RESOURCE_INFO_OID
- PG_USER
- PG_USER_MAPPINGS
- PG_VARIABLE_INFO
- PG_VIEWS
- PLAN_TABLE
- GS_FILE_STAT
- GS_OS_RUN_INFO
- GS_REDO_STAT
- GS_SESSION_STAT
- GS_SESSION_TIME
- GS_THREAD_MEMORY_CONTEXT
- Functions and Operators
- Logical Operators
- Comparison Operators
- Character Processing Functions and Operators
- Binary String Functions and Operators
- Bit String Functions and Operators
- Mode Matching Operators
- Mathematical Functions and Operators
- Date and Time Processing Functions and Operators
- Type Conversion Functions
- Geometric Functions and Operators
- Network Address Functions and Operators
- Text Search Functions and Operators
- JSON Functions
- HLL Functions and Operators
- SEQUENCE Functions
- Array Functions and Operators
- Range Functions and Operators
- Aggregate Functions
- Window Functions
- Security Functions
- Encrypted Equality Functions
- Set Returning Functions
- Conditional Expression Functions
- System Information Functions
- System Administration Functions
- Statistics Information Functions
- Trigger Functions
- Global Temporary Table Functions
- AI Feature Functions
- Other System Functions
- Internal Functions
- Obsolete Functions
- Supported Data Types
- SQL Syntax
- ABORT
- ALTER AGGREGATE
- ALTER AUDIT POLICY
- ALTER DATABASE
- ALTER DATA SOURCE
- ALTER DEFAULT PRIVILEGES
- ALTER DIRECTORY
- ALTER EXTENSION
- ALTER FOREIGN TABLE
- ALTER FUNCTION
- ALTER GROUP
- ALTER INDEX
- ALTER LANGUAGE
- ALTER LARGE OBJECT
- ALTER MASKING POLICY
- ALTER MATERIALIZED VIEW
- ALTER OPERATOR
- ALTER RESOURCE LABEL
- ALTER ROLE
- ALTER ROW LEVEL SECURITY POLICY
- ALTER RULE
- ALTER SCHEMA
- ALTER SEQUENCE
- ALTER SERVER
- ALTER SESSION
- ALTER SYNONYM
- ALTER SYSTEM KILL SESSION
- ALTER SYSTEM SET
- ALTER TABLE
- ALTER TABLE PARTITION
- ALTER TABLESPACE
- ALTER TEXT SEARCH CONFIGURATION
- ALTER TEXT SEARCH DICTIONARY
- ALTER TRIGGER
- ALTER TYPE
- ALTER USER
- ALTER USER MAPPING
- ALTER VIEW
- ANALYZE | ANALYSE
- BEGIN
- CALL
- CHECKPOINT
- CLOSE
- CLUSTER
- COMMENT
- COMMIT | END
- COMMIT PREPARED
- COPY
- CREATE AGGREGATE
- CREATE AUDIT POLICY
- CREATE CAST
- CREATE CLIENT MASTER KEY
- CREATE COLUMN ENCRYPTION KEY
- CREATE DATABASE
- CREATE DATA SOURCE
- CREATE DIRECTORY
- CREATE EXTENSION
- CREATE FOREIGN TABLE
- CREATE FUNCTION
- CREATE GROUP
- CREATE INCREMENTAL MATERIALIZED VIEW
- CREATE INDEX
- CREATE LANGUAGE
- CREATE MASKING POLICY
- CREATE MATERIALIZED VIEW
- CREATE OPERATOR
- CREATE ROW LEVEL SECURITY POLICY
- CREATE PROCEDURE
- CREATE RESOURCE LABEL
- CREATE ROLE
- CREATE RULE
- CREATE SCHEMA
- CREATE SEQUENCE
- CREATE SERVER
- CREATE SYNONYM
- CREATE TABLE
- CREATE TABLE AS
- CREATE TABLE PARTITION
- CREATE TABLESPACE
- CREATE TEXT SEARCH CONFIGURATION
- CREATE TEXT SEARCH DICTIONARY
- CREATE TRIGGER
- CREATE TYPE
- CREATE USER
- CREATE USER MAPPING
- CREATE VIEW
- CURSOR
- DEALLOCATE
- DECLARE
- DELETE
- DO
- DROP AGGREGATE
- DROP AUDIT POLICY
- DROP CAST
- DROP CLIENT MASTER KEY
- DROP COLUMN ENCRYPTION KEY
- DROP DATABASE
- DROP DATA SOURCE
- DROP DIRECTORY
- DROP EXTENSION
- DROP FOREIGN TABLE
- DROP FUNCTION
- DROP GROUP
- DROP INDEX
- DROP LANGUAGE
- DROP MASKING POLICY
- DROP MATERIALIZED VIEW
- DROP OPERATOR
- DROP OWNED
- DROP RESOURCE LABEL
- DROP ROW LEVEL SECURITY POLICY
- DROP PROCEDURE
- DROP ROLE
- DROP RULE
- DROP SCHEMA
- DROP SEQUENCE
- DROP SERVER
- DROP SYNONYM
- DROP TABLE
- DROP TABLESPACE
- DROP TEXT SEARCH CONFIGURATION
- DROP TEXT SEARCH DICTIONARY
- DROP TRIGGER
- DROP TYPE
- DROP USER
- DROP USER MAPPING
- DROP VIEW
- EXECUTE
- EXPLAIN
- EXPLAIN PLAN
- FETCH
- GRANT
- INSERT
- LOCK
- MOVE
- MERGE INTO
- PREPARE
- PREPARE TRANSACTION
- REASSIGN OWNED
- REFRESH INCREMENTAL MATERIALIZED VIEW
- REFRESH MATERIALIZED VIEW
- REINDEX
- RELEASE SAVEPOINT
- RESET
- REVOKE
- ROLLBACK
- ROLLBACK PREPARED
- ROLLBACK TO SAVEPOINT
- SAVEPOINT
- SELECT
- SELECT INTO
- SET
- SET CONSTRAINTS
- SET ROLE
- SET SESSION AUTHORIZATION
- SET TRANSACTION
- SHOW
- SHUTDOWN
- START TRANSACTION
- TRUNCATE
- UPDATE
- VACUUM
- VALUES
- SQL Reference
- MogDB SQL
- Keywords
- Constant and Macro
- Expressions
- Type Conversion
- Full Text Search
- Introduction
- Tables and Indexes
- Controlling Text Search
- Additional Features
- Parser
- Dictionaries
- Configuration Examples
- Testing and Debugging Text Search
- Limitations
- System Operation
- Controlling Transactions
- DDL Syntax Overview
- DML Syntax Overview
- DCL Syntax Overview
- Appendix
- GUC Parameters
- GUC Parameter Usage
- File Location
- Connection and Authentication
- Resource Consumption
- Parallel Import
- Write Ahead Log
- HA Replication
- Memory Table
- Query Planning
- Error Reporting and Logging
- Alarm Detection
- Statistics During the Database Running
- Load Management
- Automatic Vacuuming
- Default Settings of Client Connection
- Lock Management
- Version and Platform Compatibility
- Faut Tolerance
- Connection Pool Parameters
- MogDB Transaction
- Developer Options
- Auditing
- Upgrade Parameters
- Miscellaneous Parameters
- Wait Events
- Query
- System Performance Snapshot
- Equality Query in a Fully-encrypted Database
- Global Temporary Table
- Scheduled Task
- Thread Pool
- Appendix
- Information Schema
- DBE_PERF
- DBE_PERF Overview
- OS
- Instance
- Memory
- File
- Object
- STAT_USER_TABLES
- SUMMARY_STAT_USER_TABLES
- GLOBAL_STAT_USER_TABLES
- STAT_USER_INDEXES
- SUMMARY_STAT_USER_INDEXES
- GLOBAL_STAT_USER_INDEXES
- STAT_SYS_TABLES
- SUMMARY_STAT_SYS_TABLES
- GLOBAL_STAT_SYS_TABLES
- STAT_SYS_INDEXES
- SUMMARY_STAT_SYS_INDEXES
- GLOBAL_STAT_SYS_INDEXES
- STAT_ALL_TABLES
- SUMMARY_STAT_ALL_TABLES
- GLOBAL_STAT_ALL_TABLES
- STAT_ALL_INDEXES
- SUMMARY_STAT_ALL_INDEXES
- GLOBAL_STAT_ALL_INDEXES
- STAT_DATABASE
- SUMMARY_STAT_DATABASE
- GLOBAL_STAT_DATABASE
- STAT_DATABASE_CONFLICTS
- SUMMARY_STAT_DATABASE_CONFLICTS
- GLOBAL_STAT_DATABASE_CONFLICTS
- STAT_XACT_ALL_TABLES
- SUMMARY_STAT_XACT_ALL_TABLES
- GLOBAL_STAT_XACT_ALL_TABLES
- STAT_XACT_SYS_TABLES
- SUMMARY_STAT_XACT_SYS_TABLES
- GLOBAL_STAT_XACT_SYS_TABLES
- STAT_XACT_USER_TABLES
- SUMMARY_STAT_XACT_USER_TABLES
- GLOBAL_STAT_XACT_USER_TABLES
- STAT_XACT_USER_FUNCTIONS
- SUMMARY_STAT_XACT_USER_FUNCTIONS
- GLOBAL_STAT_XACT_USER_FUNCTIONS
- STAT_BAD_BLOCK
- SUMMARY_STAT_BAD_BLOCK
- GLOBAL_STAT_BAD_BLOCK
- STAT_USER_FUNCTIONS
- SUMMARY_STAT_USER_FUNCTIONS
- GLOBAL_STAT_USER_FUNCTIONS
- Workload
- Session/Thread
- SESSION_STAT
- GLOBAL_SESSION_STAT
- SESSION_TIME
- GLOBAL_SESSION_TIME
- SESSION_MEMORY
- GLOBAL_SESSION_MEMORY
- SESSION_MEMORY_DETAIL
- GLOBAL_SESSION_MEMORY_DETAIL
- SESSION_STAT_ACTIVITY
- GLOBAL_SESSION_STAT_ACTIVITY
- THREAD_WAIT_STATUS
- GLOBAL_THREAD_WAIT_STATUS
- LOCAL_THREADPOOL_STATUS
- GLOBAL_THREADPOOL_STATUS
- SESSION_CPU_RUNTIME
- SESSION_MEMORY_RUNTIME
- STATEMENT_IOSTAT_COMPLEX_RUNTIME
- Transaction
- Query
- STATEMENT
- SUMMARY_STATEMENT
- STATEMENT_COUNT
- GLOBAL_STATEMENT_COUNT
- SUMMARY_STATEMENT_COUNT
- GLOBAL_STATEMENT_COMPLEX_HISTORY
- GLOBAL_STATEMENT_COMPLEX_HISTORY_TABLE
- GLOBAL_STATEMENT_COMPLEX_RUNTIME
- STATEMENT_RESPONSETIME_PERCENTILE
- STATEMENT_USER_COMPLEX_HISTORY
- STATEMENT_COMPLEX_RUNTIME
- STATEMENT_COMPLEX_HISTORY_TABLE
- STATEMENT_COMPLEX_HISTORY
- STATEMENT_WLMSTAT_COMPLEX_RUNTIME
- STATEMENT_HISTORY
- Cache/IO
- STATIO_USER_TABLES
- SUMMARY_STATIO_USER_TABLES
- GLOBAL_STATIO_USER_TABLES
- STATIO_USER_INDEXES
- SUMMARY_STATIO_USER_INDEXES
- GLOBAL_STATIO_USER_INDEXES
- STATIO_USER_SEQUENCES
- SUMMARY_STATIO_USER_SEQUENCES
- GLOBAL_STATIO_USER_SEQUENCES
- STATIO_SYS_TABLES
- SUMMARY_STATIO_SYS_TABLES
- GLOBAL_STATIO_SYS_TABLES
- STATIO_SYS_INDEXES
- SUMMARY_STATIO_SYS_INDEXES
- GLOBAL_STATIO_SYS_INDEXES
- STATIO_SYS_SEQUENCES
- SUMMARY_STATIO_SYS_SEQUENCES
- GLOBAL_STATIO_SYS_SEQUENCES
- STATIO_ALL_TABLES
- SUMMARY_STATIO_ALL_TABLES
- GLOBAL_STATIO_ALL_TABLES
- STATIO_ALL_INDEXES
- SUMMARY_STATIO_ALL_INDEXES
- GLOBAL_STATIO_ALL_INDEXES
- STATIO_ALL_SEQUENCES
- SUMMARY_STATIO_ALL_SEQUENCES
- GLOBAL_STATIO_ALL_SEQUENCES
- GLOBAL_STAT_DB_CU
- GLOBAL_STAT_SESSION_CU
- Utility
- REPLICATION_STAT
- GLOBAL_REPLICATION_STAT
- REPLICATION_SLOTS
- GLOBAL_REPLICATION_SLOTS
- BGWRITER_STAT
- GLOBAL_BGWRITER_STAT
- GLOBAL_CKPT_STATUS
- GLOBAL_DOUBLE_WRITE_STATUS
- GLOBAL_PAGEWRITER_STATUS
- GLOBAL_RECORD_RESET_TIME
- GLOBAL_REDO_STATUS
- GLOBAL_RECOVERY_STATUS
- CLASS_VITAL_INFO
- USER_LOGIN
- SUMMARY_USER_LOGIN
- GLOBAL_GET_BGWRITER_STATUS
- Lock
- Wait Events
- Configuration
- Operator
- Workload Manager
- Global Plancache
- Appendix
- Tool Reference
- Tool Overview
- Client Tool
- Server Tools
- Tools Used in the Internal System
- Error Code Reference
- Description of SQL Error Codes
- Third-Party Library Error Codes
- GAUSS-00001 - GAUSS-00100
- GAUSS-00101 - GAUSS-00200
- GAUSS 00201 - GAUSS 00300
- GAUSS 00301 - GAUSS 00400
- GAUSS 00401 - GAUSS 00500
- GAUSS 00501 - GAUSS 00600
- GAUSS 00601 - GAUSS 00700
- GAUSS 00701 - GAUSS 00800
- GAUSS 00801 - GAUSS 00900
- GAUSS 00901 - GAUSS 01000
- GAUSS 01001 - GAUSS 01100
- GAUSS 01101 - GAUSS 01200
- GAUSS 01201 - GAUSS 01300
- GAUSS 01301 - GAUSS 01400
- GAUSS 01401 - GAUSS 01500
- GAUSS 01501 - GAUSS 01600
- GAUSS 01601 - GAUSS 01700
- GAUSS 01701 - GAUSS 01800
- GAUSS 01801 - GAUSS 01900
- GAUSS 01901 - GAUSS 02000
- GAUSS 02001 - GAUSS 02100
- GAUSS 02101 - GAUSS 02200
- GAUSS 02201 - GAUSS 02300
- GAUSS 02301 - GAUSS 02400
- GAUSS 02401 - GAUSS 02500
- GAUSS 02501 - GAUSS 02600
- GAUSS 02601 - GAUSS 02700
- GAUSS 02701 - GAUSS 02800
- GAUSS 02801 - GAUSS 02900
- GAUSS 02901 - GAUSS 03000
- GAUSS 03001 - GAUSS 03100
- GAUSS 03101 - GAUSS 03200
- GAUSS 03201 - GAUSS 03300
- GAUSS 03301 - GAUSS 03400
- GAUSS 03401 - GAUSS 03500
- GAUSS 03501 - GAUSS 03600
- GAUSS 03601 - GAUSS 03700
- GAUSS 03701 - GAUSS 03800
- GAUSS 03801 - GAUSS 03900
- GAUSS 03901 - GAUSS 04000
- GAUSS 04001 - GAUSS 04100
- GAUSS 04101 - GAUSS 04200
- GAUSS 04201 - GAUSS 04300
- GAUSS 04301 - GAUSS 04400
- GAUSS 04401 - GAUSS 04500
- GAUSS 04501 - GAUSS 04600
- GAUSS 04601 - GAUSS 04700
- GAUSS 04701 - GAUSS 04800
- GAUSS 04801 - GAUSS 04900
- GAUSS 04901 - GAUSS 05000
- GAUSS 05001 - GAUSS 05100
- GAUSS 05101 - GAUSS 05200
- GAUSS 05201 - GAUSS 05300
- GAUSS 05301 - GAUSS 05400
- GAUSS 05401 - GAUSS 05500
- GAUSS 05501 - GAUSS 05600
- GAUSS 05601 - GAUSS 05700
- GAUSS 05701 - GAUSS 05800
- GAUSS 05801 - GAUSS 05900
- GAUSS 05901 - GAUSS 06000
- GAUSS 06001 - GAUSS 06100
- GAUSS 06101 - GAUSS 06200
- GAUSS 06201 - GAUSS 06300
- GAUSS 06301 - GAUSS 06400
- GAUSS 06401 - GAUSS 06500
- GAUSS 06501 - GAUSS 06600
- GAUSS 06601 - GAUSS 06700
- GAUSS 06701 - GAUSS 06800
- GAUSS 06801 - GAUSS 06900
- GAUSS 06901 - GAUSS 07000
- GAUSS 07001 - GAUSS 07100
- GAUSS 07101 - GAUSS 07200
- GAUSS 07201 - GAUSS 07300
- GAUSS 07301 - GAUSS 07400
- GAUSS 07401 - GAUSS 07480
- GAUSS 50000 - GAUSS 50999
- GAUSS 51000 - GAUSS 51999
- GAUSS 52000 - GAUSS 52999
- GAUSS 53000 - GAUSS 53699
- System Catalogs and System Views
- FAQs
- Glossary
System Information Functions
Session Information Functions
-
current_catalog
Description: Name of the current database (called "catalog" in the SQL standard)
Return type: name
Example:
mogdb=# SELECT current_catalog; current_database ------------------ mogdb (1 row)
-
current_database()
Description: Name of the current database
Return type: name
Example:
mogdb=# SELECT current_database(); current_database ------------------ mogdb (1 row)
-
current_query()
Description: Text of the currently executing query, as submitted by the client (might contain more than one statement)
Return type: text
Example:
mogdb=# SELECT current_query(); current_query ------------------------- SELECT current_query(); (1 row)
-
current_schema[()]
Description: Name of current schema
Return type: name
Example:
mogdb=# SELECT current_schema(); current_schema ---------------- public (1 row)
Remarks:current_schema returns the first valid schema name in the search path. (If the search path is empty or contains no valid schema name, NULL is returned.) This is the schema that will be used for any tables or other named objects that are created without specifying a target schema.
-
current_schemas(Boolean)
Description: Names of schemas in search path
Return type: name[]
Example:
mogdb=# SELECT current_schemas(true); current_schemas --------------------- {pg_catalog,public} (1 row)
Note:
current_schemas(Boolean) returns an array of the names of all schemas presently in the search path. The Boolean option determines whether implicitly included system schemas such as pg_catalog are included in the returned search path.
NOTE:
The search path can be altered at run time by running the following command:
SET search_path TO schema [, schema, ...]
-
current_user
Description: User name of current execution context
Return type: name
Example:
mogdb=# SELECT current_user; current_user -------------- omm (1 row)
Note:current_user is the user identifier that is applicable for permission checking. Normally it is equal to the session user, but it can be changed with SET ROLE. It also changes during the execution of functions with the attribute SECURITY DEFINER.
-
definer_current_user
Description: User name of current execution context
Return type: name
Example:
mogdb=# SELECT definer_current_user(); definer_current_user ---------------------- omm (1 row)
-
pg_current_sessionid()
Description: Session ID of current execution context
Return type: text
Example:
mogdb=# SELECT pg_current_sessionid(); pg_current_sessionid ---------------------------- 1579228402.140190434944768 (1 row)
Note:pg_current_sessionid() is used to obtain the session ID in the current execution context. The structure of the value is Timestamp. Session ID. When enable_thread_pool is set to off, the actual session ID is the thread ID.
-
pg_current_sessid
Description: Session ID of current execution context
Return type: text
Example:
mogdb=# select pg_current_sessid(); pg_current_sessid ------------------- 140308875015936 (1 row)
Note: In thread pool mode, the session ID of the current session is obtained. In non-thread pool mode, the background thread ID of the current session is obtained.
-
pg_current_userid
Description: Current user ID.
Return type: text
mogdb=# SELECT pg_current_userid(); pg_current_userid ------------------- 10 (1 row)
-
tablespace_oid_name()
Description: Queries the tablespace name based on the tablespace OID.
Return type: text
Example:
mogdb=# select tablespace_oid_name(1663); tablespace_oid_name --------------------- pg_default (1 row)
-
inet_client_addr()
Description: Remote connection address. inet_client_addr returns the IP address of the current client.
NOTE:
It is available only in remote connection mode.
Return type: inet
Example:
mogdb=# SELECT inet_client_addr(); inet_client_addr ------------------ 10.10.0.50 (1 row)
-
inet_client_port()
Description: Remote connection port. And inet_client_port returns the port number of the current client.
NOTE:
It is available only in remote connection mode.
Return type: int
Example:
mogdb=# SELECT inet_client_port(); inet_client_port ------------------ 33143 (1 row)
-
inet_server_addr()
Description: Local connection address. inet_server_addr returns the IP address on which the server accepted the current connection.
NOTE:
It is available only in remote connection mode.
Return type: inet
Example:
mogdb=# SELECT inet_server_addr(); inet_server_addr ------------------ 10.10.0.13 (1 row)
-
inet_server_port()
Description: Local connection port. inet_server_port returns the port number. All these functions return NULL if the current connection is via a Unix-domain socket.
NOTE:
It is available only in remote connection mode.
Return type: int
Example:
mogdb=# SELECT inet_server_port(); inet_server_port ------------------ 8000 (1 row)
-
pg_conf_load_time()
Description: Configures load time. pg_conf_load_time returns the timestamp with time zone when the server configuration files were last loaded.
Return type: timestamp with time zone
Example:
mogdb=# SELECT pg_conf_load_time(); pg_conf_load_time ------------------------------ 2017-09-01 16:05:23.89868+08 (1 row)
-
pg_my_temp_schema()
Description: OID of the temporary schema of a session. The value is 0 if the OID does not exist.
Return type: oid
Example:
mogdb=# SELECT pg_my_temp_schema(); pg_my_temp_schema ------------------- 0 (1 row)
Note:pg_my_temp_schema returns the OID of the current session's temporary schema, or zero if it has none (because it has not created any temporary tables). pg_is_other_temp_schema returns true if the given OID is the OID of another session's temporary schema.
-
pg_is_other_temp_schema(oid)
Description: Whether the schema is the temporary schema of another session.
Return type: Boolean
Example:
mogdb=# SELECT pg_is_other_temp_schema(25356); pg_is_other_temp_schema ------------------------- f (1 row)
-
pg_listening_channels()
Description: Channel names that the session is currently listening on
Return type: SETOF text
Example:
mogdb=# SELECT pg_listening_channels(); pg_listening_channels ----------------------- (0 rows)
Note:pg_listening_channels returns a set of names of channels that the current session is listening to.
-
pg_postmaster_start_time()
Description: Server start time pg_postmaster_start_time returns the timestamp with time zone when the server started.
Return type: timestamp with time zone
Example:
mogdb=# SELECT pg_postmaster_start_time(); pg_postmaster_start_time ------------------------------ 2017-08-30 16:02:54.99854+08 (1 row)
-
pg_get_ruledef(rule_oid)
Description: Obtains the CREATE RULE command of a rule.
Return type: text
Example:
mogdb=# select * from pg_get_ruledef(24828); pg_get_ruledef ------------------------------------------------------------------- CREATE RULE t1_ins AS ON INSERT TO t1 DO INSTEAD INSERT INTO t2 (id) VALUES (new.id); (1 row)
-
sessionid2pid()
Description: Obtains PID information from a session ID (for example, the sessid column in pv_session_stat).
Return type: int8
Example:
mogdb=# select sessionid2pid(sessid::cstring) from pv_session_stat limit 2; sessionid2pid ----------------- 139973107902208 139973107902208 (2 rows)
-
pg_trigger_depth()
Description: Current nesting level of triggers
Return type: int
Example:
mogdb=# SELECT pg_trigger_depth(); pg_trigger_depth ------------------ 0 (1 row)
-
pgxc_version()
Description: Postgres-XC version information
Return type: text
Example:
mogdb=# SELECT pgxc_version(); pgxc_version ------------------------------------------------------------------------------------------------------------- Postgres-XC 1.1 on x86_64-unknown-linux-gnu, based on PostgreSQL 9.2.4, compiled by g++ (GCC) 5.4.0, 64-bit (1 row)
-
session_user
Description: Session user name
Return type: name
Example:
mogdb=# SELECT session_user; session_user -------------- omm (1 row)
Note:session_user is usually the user who initiated the current database connection, but administrators can change this setting with SET SESSION AUTHORIZATION.
-
user
Description: Equivalent to current_user.
Return type: name
Example:
mogdb=# SELECT user; current_user -------------- omm (1 row)
-
get_shard_oids_byname
Description: Returns the OID of the node when the node name is entered.
Return type: oid
Example:
mogdb=# select get_shard_oids_byname('datanode1'); get_shard_oids_byname ----------------------- {16385} (1 row)
-
getpgusername()
Description: Obtains the database username.
Return type: name
Example:
mogdb=# select getpgusername(); getpgusername --------------- MogDB_userna (1 row)
-
getdatabaseencoding()
Description: Obtains the database encoding mode.
Return type: name
Example:
mogdb=# select getdatabaseencoding(); getdatabaseencoding --------------------- SQL_ASCII (1 row)
-
version()
Description: version information. version returns a string describing a server's version.
Return type: text
Example:
mogdb=# SELECT version(); version --------------------------------------------------------------------------------------------------------------------------------------- PostgreSQL 9.2.4 (MogDB 2.0.1 build f892ccb7) compiled at 2021-07-09 16:12:59 commit 0 last mr on x86_64-unknown-linux-gnu, compiled by g++ (GCC) 8.2.0, 64-bit (1 row)
-
get_hostname()
Description: Returns the hostname of the current node.
Return type: text
Example:
mogdb=# SELECT get_hostname(); get_hostname -------------- linux-user (1 row)
-
get_nodename()
Description: Returns the name of the current node.
Return type: text
Example:
mogdb=# SELECT get_nodename(); get_nodename -------------- coordinator1 (1 row)
-
get_schema_oid(cstring)
Description: Returns the OID of the queried schema.
Return type: oid
Example:
mogdb=# SELECT get_schema_oid('public'); get_schema_oid ---------------- 2200 (1 row)
-
pgxc_prepared_xact()
Description: Returns the list of transaction GIDs at the prepared stage in the cluster.
Return type: SETOF text
Example:
mogdb=# SELECT pgxc_prepared_xact(); pgxc_prepared_xact -------------------- (0 row)
Access privilege inquiry function
-
has_any_column_privilege(user, table, privilege)
Description: Queries whether a specified user has permission for any column of table.
Table 1 Parameter type description
Parameter Valid Input Parameter Type user name, oid table text, oid privilege text Return type: Boolean
-
has_any_column_privilege(table, privilege)
Description: Queries whether the current user has permission to access any column of table. For details about the valid parameter types, see [Table 1](#table 1 parameter type).
Return type: Boolean
has_any_column_privilege checks whether a user can access any column of a table in a particular way. Its parameter possibilities are analogous to has_table_privilege, except that the desired access permission type must be some combination of SELECT, INSERT, UPDATE, or REFERENCES.
NOTE:
Note that having any of these permissions at the table level implicitly grants it for each column of the table, so has_any_column_privilege will always return true if has_table_privilege does for the same parameters. But has_any_column_privilege also succeeds if there is a column-level grant of the permission for at least one column.
-
has_column_privilege(user, table, column, privilege)
Description: Queries whether a specified user has permission for column.
Table 2 Parameter type description
Parameter Valid Input Parameter Type user name, oid table text, oid column text, smallint privilege text Return type: Boolean
-
has_column_privilege(table, column, privilege)
Description: Queries whether the current user has permission to access columns. For details about the valid parameter types, see [Table 2](#table 2 parameter type).
Return type: Boolean
has_column_privilege checks whether a user can access a column in a particular way. Its argument possibilities are analogous to has_table_privilege, with the addition that the column can be specified either by name or attribute number. The desired access permission type must evaluate to some combination of SELECT, INSERT, UPDATE, or REFERENCES.
NOTE:
Note that having any of these permissions at the table level implicitly grants it for each column of the table.
-
has_cek_privilege(user, cek, privilege)
Description: Queries whether a specified user has permission for CEK. For details about the valid parameter types, see [Table 3](#table 3 parameter type).
Table 3 Parameter type description
Parameter Valid Input Parameter Type Description Value Range user name, oid User User name or ID cek text, oid CEK CEK name or ID privilege text Permission Usage: A specified CEK is allowed to be used.
DROP: A specified CEK is allowed to be deleted.Return type: Boolean
-
has_cmk_privilege(user, cmk, privilege)
Description: Queries whether a specified user has permission for CMK. For details about the valid parameter types, see [Table 4](#table 4 parameter type).
Table 4 Parameter type description
Parameter Valid Input Parameter Type Description Value Range user name,oid User User name or ID cmk text,oid CMK CMK name or ID privilege text Permission Usage: A specified CMK is allowed to be used.
DROP: A specified CMK is allowed to be deleted.Return type: Boolean
-
has_database_privilege(user, database, privilege)
Description: Queries whether a specified user has permission for database.
Table 5 Parameter type description
Parameter Valid Input Parameter Type user name, oid database text, oid privilege text Return type: Boolean
-
has_database_privilege(database, privilege)
Description: Queries whether the current user has permission to access a database. For details about the valid parameter types, see [Table 5](#table 5 parameter type).
Return type: Boolean
Note:has_database_privilege checks whether a user can access a database in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to some combination of CREATE, CONNECT, TEMPORARY, or TEMP (which is equivalent to TEMPORARY).
-
has_directory_privilege(user, database, privilege)
Description: Queries whether a specified user has permission for directory.
Table 6 Parameter type description
Parameter Valid Input Parameter Type user name, oid database text, oid privilege text Return type: Boolean
-
has_directory_privilege(database, privilege)
Description: Queries whether the current user has permission to access a directory. For details about the valid parameter types, see [Table 6](#table 6 parameter type).
Return type: Boolean
-
has_foreign_data_wrapper_privilege(user, fdw, privilege)
Description: Queries whether a specified user has permission for foreign-data wrapper.
Table 7 Parameter type description
Parameter Valid Input Parameter Type user name, oid fdw text, oid privilege text Return type: Boolean
-
has_foreign_data_wrapper_privilege(fdw, privilege)
Description: Queries whether the current user has permission for foreign-data wrapper. For details about valid parameter types, see [Table 7](#table 7 parameter type).
Return type: Boolean
Note:has_foreign_data_wrapper_privilege checks whether a user can access a foreign-data wrapper in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to USAGE.
-
has_function_privilege(user, function, privilege)
Description: Queries whether a specified user has permission for function.
Table 8 Parameter type description
Parameter Valid Input Parameter Type user name, oid function text, oid privilege text Return type: Boolean
-
has_function_privilege(function, privilege)
Description: Queries whether the current user has permission for function. For details about valid parameter types, see [Table 8](#table 8 parameter type).
Return type: Boolean
Note:has_function_privilege checks whether a user can access a function in a particular way. Its argument possibilities are analogous to has_table_privilege. When a function is specified by a text string rather than by OID, the allowed input is the same as that for the regprocedure data type (see Object Identifier Types). The desired access permission type must evaluate to EXECUTE.
-
has_language_privilege(user, language, privilege)
Description: Queries whether a specified user has permission for language.
Table 9 Parameter type description
Parameter Valid Input Parameter Type user name, oid language text, oid privilege text Return type: Boolean
-
has_language_privilege(language, privilege)
Description: Queries whether the current user has permission for language. For details about valid parameter types, see [Table 9](#table 9 parameter type).
Return type: Boolean
Note:has_language_privilege checks whether a user can access a procedural language in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to USAGE.
-
has_nodegroup_privilege (user, nodegroup, privilege)
Description: Checks whether a user has permission to access a cluster node.
Return type: Boolean
Table 10 Parameter type description
Parameter Valid Input Parameter Type user name, oid nodegroup text, oid privilege text -
has_nodegroup_privilege (nodegroup, privilege)
Description: Checks whether a user has permission to access a cluster node.
Return type: Boolean
-
has_schema_privilege(user, schema, privilege)
Description: Queries whether a specified user has permission for schema.
Return type: Boolean
-
has_schema_privilege(schema, privilege)
Description: Queries whether the current user has permission for schema.
Return type: Boolean
Note:has_schema_privilege checks whether a user can access a schema in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to some combination of CREATE or USAGE.
-
has_server_privilege(user, server, privilege)
Description: Queries whether a specified user has permission for foreign server.
Return type: Boolean
-
has_server_privilege(server, privilege)
Description: Queries whether the current user has permission for foreign server.
Return type: Boolean
Note:has_server_privilege checks whether a user can access a foreign server in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to USAGE.
-
has_table_privilege(user, table, privilege)
Description: Queries whether a specified user has permission for table.
Return type: Boolean
-
has_table_privilege(table, privilege)
Description: Queries whether the current user has permission for table.
Return type: Boolean
has_table_privilege checks whether a user can access a table in a particular way. The user can be specified by name, by OID (pg_authid.oid), public to indicate the PUBLIC pseudo-role, or if the argument is omitted current_user is assumed. The table can be specified by name or by OID. When specifying by name, the name can be schema-qualified if necessary. The desired access permission type is specified by a text string, which must be one of the values SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, or TRIGGER. Optionally, WITH GRANT OPTION can be added to a permission type to test whether the permission is held with grant option. Also, multiple permission types can be listed separated by commas, in which case the result will be true if any of the listed permissions is held.
Example:
mogdb=# SELECT has_table_privilege('tpcds.web_site', 'select'); has_table_privilege --------------------- t (1 row) mogdb=# SELECT has_table_privilege('omm', 'tpcds.web_site', 'select,INSERT WITH GRANT OPTION '); has_table_privilege --------------------- t (1 row)
-
has_tablespace_privilege(user, tablespace, privilege)
Description: Queries whether a specified user has permission for tablespace.
Return type: Boolean
-
has_tablespace_privilege(tablespace, privilege)
Description: Queries whether the current user has permission for tablespace.
Return type: Boolean
Note:has_tablespace_privilege checks whether a user can access a tablespace in a particular way. Its argument possibilities are analogous to has_table_privilege. The desired access permission type must evaluate to CREATE.
-
pg_has_role(user, role, privilege)
Description: Queries whether a specified user has permission for role.
Return type: Boolean
-
pg_has_role(role, privilege)
Description: Specifies whether the current user has permission for role.
Return type: Boolean
Note:pg_has_role checks whether a user can access a role in a particular way. Its argument possibilities are analogous to has_table_privilege, except that public is not allowed as a user name. The desired access permission type must evaluate to some combination of MEMBER or USAGE. MEMBER denotes direct or indirect membership in the role (that is, the right to do SET ROLE), while USAGE denotes the permissions of the role are available without doing SET ROLE.
Schema Visibility Inquiry Functions
Each function performs the visibility check for one type of database object. For functions and operators, an object in the search path is visible if there is no object of the same name and argument data type(s) earlier in the path. For operator classes, both name and associated index access method are considered.
All these functions require object OIDs to identify the object to be checked. If you want to test an object by name, it is convenient to use the OID alias types (regclass, regtype, regprocedure, regoperator, regconfig, or regdictionary).
For example, a table is said to be visible if its containing schema is in the search path and no table of the same name appears earlier in the search path. This is equivalent to the statement that the table can be referenced by name without explicit schema qualification. For example, to list the names of all visible tables:
mogdb=# SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
-
pg_collation_is_visible(collation_oid)
Description: Queries whether the collation is visible in search path.
Return type: Boolean
-
pg_conversion_is_visible(conversion_oid)
Description: Queries whether the conversion is visible in search path.
Return type: Boolean
-
pg_function_is_visible(function_oid)
Description: Queries whether the function is visible in search path.
Return type: Boolean
-
pg_opclass_is_visible(opclass_oid)
Description: Queries whether the operator class is visible in search path.
Return type: Boolean
-
pg_operator_is_visible(operator_oid)
Description: Queries whether the operator is visible in search path.
Return type: Boolean
-
pg_opfamily_is_visible(opclass_oid)
Description: Queries whether the operator family is visible in search path.
Return type: Boolean
-
pg_table_is_visible(table_oid)
Description: Queries whether the table is visible in search path.
Return type: Boolean
-
pg_ts_config_is_visible(config_oid)
Description: Queries whether the text search configuration is visible in search path.
Return type: Boolean
-
pg_ts_dict_is_visible(dict_oid)
Description: Queries whether the text search dictionary is visible in search path.
Return type: Boolean
-
pg_ts_parser_is_visible(parser_oid)
Description: Queries whether the text search parser is visible in search path.
Return type: Boolean
-
pg_ts_template_is_visible(template_oid)
Description: Queries whether the text search template is visible in search path.
Return type: Boolean
-
pg_type_is_visible(type_oid)
Description: Queries whether the type (or domain) is visible in search path.
Return type: Boolean
System Catalog Information Functions
-
format_type(type_oid, typemod)
Description: Gets SQL name of a data type.
Return type: text
Note:format_type returns the SQL name of a data type that is identified by its type OID and possibly a type modifier. Pass NULL for the type modifier if no specific modifier is known. Certain type modifiers are passed for data types with length limitations. The SQL name returned from format_type contains the length of the data type, which can be calculated by taking sizeof(int32) from actual storage length [actual storage len - sizeof(int32)] in the unit of bytes. 32-bit space is required to store the customized length set by users. So the actual storage length contains 4 bytes more than the customized length. In the following example, the SQL name returned from format_type is character varying(6), indicating the length of varchar type is 6 bytes. So the actual storage length of varchar type is 10 bytes.
mogdb=# SELECT format_type((SELECT oid FROM pg_type WHERE typname='varchar'), 10); format_type ---------------------- character varying(6) (1 row)
-
pg_check_authid(role_oid)
Description: Check whether a role name with given OID exists.
Return type: bool
Example:
mogdb=# select pg_check_authid(1); pg_check_authid ----------------- f (1 row)
-
pg_describe_object(catalog_id, object_id, object_sub_id)
Description: Gets description of a database object.
Return type: text
Note:pg_describe_object returns a description of a database object specified by catalog OID, object OID and a (possibly zero) sub-object ID. This is useful to determine the identity of an object as stored in the pg_depend catalog.
-
pg_get_constraintdef(constraint_oid)
Description: Gets definition of a constraint.
Return type: text
-
pg_get_constraintdef(constraint_oid, pretty_bool)
Description: Gets definition of a constraint.
Return type: text
Note:pg_get_constraintdef and pg_get_indexdef respectively reconstruct the creating command for a constraint and an index.
-
pg_get_expr(pg_node_tree, relation_oid)
Description: Decompiles internal form of an expression, assuming that any Vars in it refer to the relationship indicated by the second parameter.
Return type: text
-
pg_get_expr(pg_node_tree, relation_oid, pretty_bool)
Description: Decompiles internal form of an expression, assuming that any Vars in it refer to the relationship indicated by the second parameter.
Return type: text
Note:pg_get_expr decompiles the internal form of an individual expression, such as the default value for a column. It can be useful when examining the contents of system catalogs. If the expression might contain Vars, specify the OID of the relationship they refer to as the second parameter; if no Vars are expected, zero is sufficient.
-
pg_get_functiondef(func_oid)
Description: Gets definition of a function.
Return type: text
Example:
mogdb=# select * from pg_get_functiondef(598); headerlines | definition -------------+---------------------------------------------------- 4 | CREATE OR REPLACE FUNCTION pg_catalog.abbrev(inet)+ | RETURNS text + | LANGUAGE internal + | IMMUTABLE STRICT NOT FENCED NOT SHIPPABLE + | AS $function$inet_abbrev$function$ + | (1 row)
-
pg_get_function_arguments(func_oid)
Description: Gets argument list of function's definition (with default values).
Return type: text
Note:pg_get_function_arguments returns the argument list of a function, in the form it would need to appear in within CREATE FUNCTION.
-
pg_get_function_identity_arguments(func_oid)
Description: Gets argument list to identify a function (without default values).
Return type: text
Note:pg_get_function_identity_arguments returns the argument list necessary to identify a function, in the form it would need to appear in within ALTER FUNCTION. This form omits default values.
-
pg_get_function_result(func_oid)
Description: Gets RETURNS clause for function.
Return type: text
Note:pg_get_function_result returns the appropriate RETURNS clause for the function.
-
pg_get_indexdef(index_oid)
Description: Gets CREATE INDEX command for index.
Return type: text
Example:
mogdb=# select * from pg_get_indexdef(16416); pg_get_indexdef ------------------------------------------------------------------------- CREATE INDEX test3_b_idx ON test3 USING btree (b) TABLESPACE pg_default (1 row)
-
pg_get_indexdef(index_oid, column_no, pretty_bool)
Description: Gets CREATE INDEX command for index, or definition of just one index column when column_no is not zero.
Example:
mogdb=# select * from pg_get_indexdef(16416, 0, false); pg_get_indexdef ------------------------------------------------------------------------- CREATE INDEX test3_b_idx ON test3 USING btree (b) TABLESPACE pg_default (1 row) mogdb=# select * from pg_get_indexdef(16416, 1, false); pg_get_indexdef ----------------- b (1 row)
Return type: text
-
pg_get_keywords()
Description: Gets list of SQL keywords and their categories.
Return type: SETOF record
Note:pg_get_keywords returns a set of records describing the SQL keywords recognized by the server. The word column contains the keyword. The catcode column contains a category code:U for unreserved, C for column name, T for type or function name, or R for reserved. The catdesc column contains a possibly-localized string describing the category.
-
pg_get_userbyid(role_oid)
Description: Gets role name with given OID.
Return type: name
Note:pg_get_userbyid extracts a role's name given its OID.
-
pg_check_authid(role_id)
Description: Checks whether a user exists based on role_id.
Return type: text
Example:
mogdb=# select pg_check_authid(20); pg_check_authid ----------------- f (1 row)
-
pg_get_viewdef(view_name)
Description: Gets underlying SELECT command for view.
Return type: text
-
pg_get_viewdef(view_name, pretty_bool)
Description: Gets underlying SELECT command for view, lines with columns are wrapped to 80 columns if pretty_bool is true.
Return type: text
Note:pg_get_viewdef reconstructs the SELECT query that defines a view. Most of these functions come in two variants. When the function has the parameter pretty_bool and the value is true, it can optionally "pretty-print" the result. The pretty-printed format is more readable. The other one is default format which is more likely to be interpreted the same way by future versions of PostgreSQL. Avoid using pretty-printed output for dump purposes. Passing false for the pretty-print parameter yields the same result as the variant that does not have the parameter at all.
-
pg_get_viewdef(view_oid)
Description: Gets underlying SELECT command for view.
Return type: text
-
pg_get_viewdef(view_oid, pretty_bool)
Description: Gets underlying SELECT command for view, lines with columns are wrapped to 80 columns if pretty_bool is true.
Return type: text
-
pg_get_viewdef(view_oid, wrap_column_int)
Description: Gets underlying SELECT command for view, wrapping lines with columns as specified, printing is implied.
Return type: text
-
pg_get_tabledef(table_oid)
Description: Obtains a table definition based on table_oid.
Example:
mogdb=# select * from pg_get_tabledef(16384); pg_get_tabledef ------------------------------------------------------- SET search_path = public; + CREATE TABLE t1 ( + c1 bigint DEFAULT nextval('serial'::regclass)+ ) + WITH (orientation=row, compression=no) + DISTRIBUTE BY HASH(c1) + TO GROUP group1; (1 row)
Return type: text
-
pg_get_tabledef(table_name)
Description: Obtains a table definition based on table_name.
Example:
mogdb=# select * from pg_get_tabledef('t1'); pg_get_tabledef ------------------------------------------------------- SET search_path = public; + CREATE TABLE t1 ( + c1 bigint DEFAULT nextval('serial'::regclass)+ ) + WITH (orientation=row, compression=no) + DISTRIBUTE BY HASH(c1) + TO GROUP group1; (1 row)
Return type: text
Remarks:pg_get_tabledef reconstructs the CREATE statement of the table definition, including the table definition, index information, and comments. Users need to create the dependent objects of the table, such as groups, schemas, tablespaces, and servers. The table definition does not include the statements for creating these dependent objects.
-
pg_options_to_table(reloptions)
Description: Gets the set of storage option name/value pairs.
Return type: SETOF record
Note:pg_options_to_table returns the set of storage option name/value pairs (option_name/option_value) when passed pg_class.reloptions or pg_attribute.attoptions.
-
pg_tablespace_databases(tablespace_oid)
Description: Gets the set of database OIDs that have objects in the specified tablespace.
Return type: SETOF oid
Note:pg_tablespace_databases allows a tablespace to be examined. It returns the set of OIDs of databases that have objects stored in the tablespace. If this function returns any rows, the tablespace is not empty and cannot be dropped. To display the specific objects populating the tablespace, you will need to connect to the databases identified by pg_tablespace_databases and query their pg_class catalogs.
-
pg_tablespace_location(tablespace_oid)
Description: Gets the path in the file system that this tablespace is located in.
Return type: text
-
pg_typeof(any)
Description: Gets the data type of any value.
Return type: regtype
Note:pg_typeof returns the OID of the data type of the value that is passed to it. This can be helpful for troubleshooting or dynamically constructing SQL queries. The function is declared as returning regtype, which is an OID alias type (see Object Identifier Types). This means that it is the same as an OID for comparison purposes but displays as a type name.
Example:
mogdb=# SELECT pg_typeof(33); pg_typeof ----------- integer (1 row) mogdb=# SELECT typlen FROM pg_type WHERE oid = pg_typeof(33); typlen -------- 4 (1 row)
-
collation for (any)
Description: Gets the collation of the parameter.
Return type: text
Note: The expression collation for returns the collation of the value that is passed to it.
Example:
mogdb=# SELECT collation for (description) FROM pg_description LIMIT 1; pg_collation_for ------------------ "default" (1 row)
The value might be quoted and schema-qualified. If no collation is derived for the argument expression, then a null value is returned. If the parameter is not of a collectable data type, then an error is thrown.
-
getdistributekey(table_name)
Description: Obtains a distribution key for a hash table.
Return type: text
Example:
mogdb=# SELECT getdistributekey('item'); getdistributekey ------------------ i_item_sk (1 row)
-
pg_extension_update_paths(name)
Description: Returns the version update path of the specified extension.
Return type: text(source text), text(path text), text(target text)
-
pg_get_serial_sequence(tablename, colname)
Description: Obtains the sequence of the corresponding table name and column name.
Return type: text
Example:
mogdb=# select * from pg_get_serial_sequence('t1', 'c1'); pg_get_serial_sequence ------------------------ public.serial (1 row)
-
pg_sequence_parameters(sequence_oid)
Description: Obtains the parameters of a specified sequence, including the start value, minimum value, maximum value, and incremental value.
Return type: bigint, bigint, bigint, bigint, Boolean
Example:
mogdb=# select * from pg_sequence_parameters(16420); start_value | minimum_value | maximum_value | increment | cycle_option -------------+---------------+---------------------+-----------+-------------- 101 | 1 | 9223372036854775807 | 1 | f (1 row)
-
pgxc_get_variable_info()
Description: Obtains variable values on the node, including nodeName, nextOid, nextXid, oldestXid, xidVacLimit, oldestXidDB, lastExtendCSNLogpage, startExtendCSNLogpage, nextCommitSeqNo, latestCompleteXid, and startupMaxXid.
Return type: set of pg_variable_info
Example:
mogdb=# select pgxc_get_variable_info( ); pgxc_get_variable_info ------------------------------------------------------------------------- (dn_6004_6005_6006,25617,141396349,2073,20000002073,15808,138111,0,127154152,141396348,104433004) (1 row)
Comment Information Functions
-
col_description(table_oid, column_number)
Description: Gets comment for a table column.
Return type: text
Note:col_description returns the comment for a table column, which is specified by the OID of its table and its column number.
-
obj_description(object_oid, catalog_name)
Description: Gets comment for a database object.
Return type: text
Note: The two-parameter form of obj_description returns the comment for a database object specified by its OID and the name of the containing system catalog. For example, obj_description(123456,'pg_class') would retrieve the comment for the table with OID 123456. The one-parameter form of obj_description requires only the object OID.
obj_description cannot be used for table columns since columns do not have OIDs of their own.
-
obj_description(object_oid)
Description: Gets comment for a database object.
Return type: text
-
shobj_description(object_oid, catalog_name)
Description: Gets comment for a shared database object.
Return type: text
Note:shobj_description is used just like obj_description except the former is used for retrieving comments on shared objects. Some system catalogs are global to all databases in MogDB, and the comments for objects in them are stored globally as well.
Transaction IDs and Snapshots
The following functions provide server transaction information in an exportable form. The main use of these functions is to determine which transactions were committed between two snapshots.
-
pgxc_is_committed(transaction_id)
Description: Determines whether the given XID is committed or ignored. NULL indicates the unknown status (such as running, preparing, and freezing).
Return type: bool
-
txid_current()
Description: Gets current transaction ID.
Return type: bigint
-
txid_current_snapshot()
Description: Gets current snapshot.
Return type: txid_snapshot
-
txid_snapshot_xip(txid_snapshot)
Description: Gets in-progress transaction IDs in snapshot.
Return type: setof bigint
-
txid_snapshot_xmax(txid_snapshot)
Description: Gets xmax of snapshot.
Return type: bigint
-
txid_snapshot_xmin(txid_snapshot)
Description: Gets xmin of snapshot.
Return type: bigint
-
txid_visible_in_snapshot(bigint, txid_snapshot)
Description: Queries whether the transaction ID is visible in snapshot. (do not use with subtransaction ids)
Return type: Boolean
-
get_local_prepared_xact()
Description: Obtains the two-phase residual transaction information of the current node, including the transaction ID, GID the two-phase transaction, prepared time, owner OID, database OID, and name of the current node.
Return type: xid, text, timestamptz, oid, oid, text
-
get_remote_prepared_xacts()
Description: Obtains the two-phase residual transaction information of all remote nodes, including the transaction ID, GID the two-phase transaction, prepared time, owner name, database name, and node name.
Return type: xid, text, timestamptz, name, name, text
-
global_clean_prepared_xacts(text, text)
Description: Concurrently cleans two-phase residual transactions. Only the gs_clean tool can call this function for the cleaning. In other situations, false is returned.
Return type: Boolean
-
pgxc_stat_get_wal_senders_status()
Description: Returns the reception status of the standby node for node transaction logs.
After the command is executed, the following result is output:
Table 11 pgxc_stat_get_wal_senders_status output parameters
Column Description nodename Name of the primary node source_ip IP address of the primary node source_port Port of the primary node dest_ip IP address of the standby node dest_port Port of the standby node sender_pid PID of the sending thread local_role Type of the primary node peer_role Type of the standby node peer_state Status of the standby node state WAL sender status sender_sent_location Sending position of the primary node sender_write_location Writing position of the primary node sender_replay_location Redo position of the primary node receiver_received_location Receiving position of the standby node receiver_write_location Writing position of the standby node receiver_flush_location Flushing location of the standby node receiver_replay_location Redo location of the standby node
The internal transaction ID type (xid) is 64 bits wide. txid_snapshot, the data type used by these functions, stores information about transaction ID visibility at a particular moment in time. Table 12 describes its components.
Name | Description |
---|---|
xmin | Earliest transaction ID (txid) that is still active. All earlier transactions will either be committed and visible, or rolled back. |
xmax | First as-yet-unassigned txid. All txids greater than or equal to this are not yet started as of the time of the snapshot, so they are invisible. |
xip_list | Active txids at the time of the snapshot. The list includes only those active txids between xmin and xmax; there might be active txids higher than xmax. A txid that is xmin <= txid < xmax and not in this list was already completed at the time of the snapshot, and is either visible or dead according to its commit status. The list does not include txids of subtransactions. |
txid_snapshot's textual representation is xmin:xmax:xip_list.
For example, 10:20:10,14,15 means xmin=10, xmax=20, xip_list=10, 14, 15.
-
slice(hstore, text[])
Description: Extracts the subset of the hstore type.
Return type: hstore
Example:
mogdb=# select slice('a=>1,b=>2,c=>3'::hstore, ARRAY['b','c','x']); slice -------------------- "b"=>"2", "c"=>"3" (1 row)
-
slice_array(hstore, text[])
Description: Extracts the set of hstore values.
Return type: value array
Example:
mogdb=# select slice_array('a=>1,b=>2,c=>3'::hstore, ARRAY['b','c','x']); slice_array ------------- {2,3,NULL} (1 row)
-
skeys(hstore)
Description: Returns a set of all keys of the hstore type.
Return type: a set of keys
Example:
mogdb=# select skeys('a=>1,b=>2'); skeys ------- a b (2 rows)
-
simsearch_lib_load_status()
Description: Queries the dynamic library loading status (success or failure).
Return type: SETOF record
-
simsearch_gpu_vector_status()
Description: Queries whether there is a vector in the status of searchlet.
Return type: SETOF record
-
pg_control_system()
Description: Returns the system control file status.
Return type: SETOF record
-
pg_control_checkpoint()
Description: Returns the system checkpoint status.
Return type: SETOF record