Updated on 2024-08-20 GMT+08:00

System Information Functions

Session Information Functions

  • SYS_CONTEXT()

    Description: Returns the value of the parameter associated with the context namespace at the current time.

    Return type: text

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    12
    13
    14
    15
    16
    17
    SELECT SYS_CONTEXT('userenv','NLS_CURRENCY');
     sys_context 
    -------------
     $
    (1 row)
    
    SELECT SYS_CONTEXT('userenv','NLS_DATE_FORMAT');
      sys_context  
    ---------------
     ISO, MDY
    (1 row)
    
    SELECT SYS_CONTEXT('userenv','NLS_DATE_LANGUAGE');
     sys_context 
    -------------
     en_US.UTF-8
    (1 row)
    
  • current_catalog()

    Description: Name of the current database (called "catalog" in the SQL standard)

    Return type: name

    Example:

    1
    2
    3
    4
    5
    testdb=# SELECT current_catalog;
     current_database
    ------------------  
     testdb
    (1 row)
    
  • current_database()

    Description: Name of the current database

    Return type: name

    Example:

    1
    2
    3
    4
    5
    testdb=# SELECT current_database();
     current_database
    ------------------
     testdb
    (1 row)
    
  • current_query()

    Description: Text of the currently executing query committed by the client (which might contain more than one statement)

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT current_query();
          current_query
    -------------------------
     SELECT current_query();
    (1 row)
    
  • current_schema[()]

    Description: Name of the current schema

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT current_schema();
     current_schema
    ----------------
     public
    (1 row)
    

    Note: 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: Name of a schema in the search path

    Return type: name[]

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT current_schemas(true);
       current_schemas
    ---------------------
     {pg_catalog,public}
    (1 row)
    

    Note:

    current_schemas(Boolean) returns an array of the names of all schemas in the search path. The Boolean option specifies whether implicitly included system schemas such as pg_catalog are included in the returned search path.

    The search path can be altered at the run time. The command is as follows:

    1
    SET search_path TO schema [, schema, ...]
    
  • database()

    Description: Returns the name of the current schema.

    Parameter: none

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT database();
     database 
    ----------
     public
    (1 row)
    

    This function is valid in a MySQL-compatible database when b_format_version is set to '5.7' and b_format_dev_version is set to 's1'.

  • current_user()

    Description: Username of current execution context

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT current_user;
     current_user
    --------------
     omm
    (1 row)
    

    Note: current_user is the user identifier used for permission check. Generally, it indicates a session user, which can be modified by SET ROLE. During function execution, it is affected by the SECURITY DEFINER attribute.

  • definer_current_user

    Description: Username of current execution context

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT definer_current_user();
     definer_current_user
    ----------------------
     omm
    (1 row)
    

    Note: Generally, the results of definer_current_user and current_user are the same. However, when this function is executed in a stored procedure, the name of user who defines the current stored procedure is returned.

  • pg_current_sessionid()

    Description: Session ID in the current execution environment.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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 operating environment. The format of the value is Timestamp.Session ID. When enable_thread_pool is disabled, the actual session ID is the thread ID.

  • pg_current_sessid()

    Description: Session ID in the current operating environment.

    Return type: text

    Example:

    gaussdb=# 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 backend thread ID of the current session is obtained.

  • pg_current_userid()

    Description: Current user ID

    Return type: text

    Example:

    gaussdb=# SELECT pg_current_userid();
    pg_current_userid
    -------------------
    10
    (1 row)
  • tablespace_oid_name(oid)

    Description: Queries the tablespace name based on the tablespace OID.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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.

    It is available only in remote connection mode.

    Return type: inet

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT inet_client_addr();
     inet_client_addr
    ------------------
     10.10.0.50
    (1 row)
    
  • inet_client_port()

    Description: Remote connection port. inet_client_port returns the port number of the current client.

    This function is valid only in remote connection mode.

    Return type: int

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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 accepts the current connection.

    It is available only in remote connection mode.

    Return type: inet

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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 number of the port receiving the current connection. All these functions return NULL if the current connection is via a UDS.

    This function is valid only in remote connection mode.

    Return type: int

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT inet_server_port();
     inet_server_port
    ------------------
                 8000
    (1 row)
    
  • pg_backend_pid()

    Description: Thread ID of the service thread connected to the current session.

    Return type: int

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT pg_backend_pid();
     pg_backend_pid
    -----------------
     140229352617744
    (1 row)
    
  • pg_conf_load_time()

    Description: Configures load time. pg_conf_load_time returns the timestamp when the server configuration files were last loaded.

    Return type: timestamp with time zone

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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:

    1
    2
    3
    4
    5
    gaussdb=# 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 0 if it has no temporary schemas (because no temporary tables are created). 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: Specifies whether the schema is the temporary schema of another session.

    Return type: Boolean

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT pg_is_other_temp_schema(25356);
     pg_is_other_temp_schema
    -------------------------
     f
    (1 row)
    
  • pg_listening_channels()

    Description: Name of the channel that the session is currently listening to.

    Return type: setof text

    Example:

    1
    2
    3
    4
    gaussdb=# 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 currently listening to.

  • pg_postmaster_start_time()

    Description: Server start time. pg_postmaster_start_time returns the timestamp with time zone when the server is started.

    Return type: timestamp with time zone

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT pg_postmaster_start_time();
       pg_postmaster_start_time   
    ------------------------------
     2017-08-30 16:02:54.99854+08
    (1 row)
    
  • sessionid2pid()

    Description: Obtains PID information from a session ID (for example, the sessid column in pv_session_stat).

    Return type: int8

    Example:

    1
    2
    3
    4
    5
    6
    gaussdb=# select sessionid2pid(sessid::cstring) from pv_session_stat limit 2;
      sessionid2pid
    -----------------
     139973107902208
     139973107902208
    (2 rows)
    
  • session_context( 'namespace' , 'parameter')

    Description: Obtains and returns the parameter values of a specified namespace.

    Return type: VARCHAR

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT session_context('USERENV', 'CURRENT_SCHEMA');
     session_context 
    -------------
     public
    (1 row)
    

    The result varies according to the current actual schema.

    Note: Currently, only the SESSION_CONTEXT('USERENV', 'CURRENT_SCHEMA') and SESSION_CONTEXT('USERENV', 'CURRENT_USER') formats are supported.

  • pg_trigger_depth()

    Description: Nesting level of triggers.

    Return type: int

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT pg_trigger_depth();
     pg_trigger_depth 
    ------------------
                    0
    (1 row)
    
  • opengauss_version()

    Description: Referenced openGauss kernel version.

    Return type: text

    The following is an example. Replace x.x.x in the query result with the actual value.

    1
    2
    3
    4
    5
    gaussdb=# SELECT opengauss_version();
     opengauss_version
    -------------------
     x.x.x
    (1 row)
    
  • gs_deployment()

    Description: Deployment mode of the current system. For a distributed system, Distribute is returned.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT gs_deployment();
     gs_deployment
    ---------------
     Distribute
    (1 row)
    
  • session_user

    Description: Session username.

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT session_user;
     session_user
    --------------
     omm
    (1 row)
    

    Note: session_user usually specifies the initial user connected to the current database, but the system administrator can change this setting by using SET SESSION AUTHORIZATION.

  • user

    Description: Equivalent to current_user.

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# 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:

    1
    2
    3
    4
    5
    gaussdb=# SELECT get_shard_oids_byname('datanode1');
     get_shard_oids_byname
    -----------------------
     {16385}
    (1 row)
    
  • getpgusername()

    Description: Obtains the database username.

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT getpgusername();
     getpgusername 
    ---------------
     GaussDB_userna
    (1 row)
    
  • getdatabaseencoding()

    Description: Obtains the database encoding mode.

    Return type: name

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT getdatabaseencoding();
     getdatabaseencoding 
    ---------------------
     SQL_ASCII
    (1 row)
    
  • version()

    Description: version information. version returns a string describing a server's version.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT version();
                                                                                             version
    -----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
     gaussdb (GaussDB XXX.XXX.XXX build f521c606) compiled at 2021-09-16 14:55:22 commit 2935 last mr 6385 release
    (1 row)
    
  • working_version_num()

    Description: version number. It returns a version number related to system compatibility.

    Return type: int

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT working_version_num();
     working_version_num
    ---------------------
                   92231
    (1 row)
    
  • get_hostname()

    Description: Returns the host name of the current node.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT get_hostname();
     get_hostname
    --------------
     linux-user
    (1 row)
    
  • get_nodename()

    Description: Returns the name of the current node.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT get_nodename();
     get_nodename
    --------------
     coordinator1
    (1 row)
    
  • get_nodeinfo(text)

    Description: Returns the value of the corresponding node information based on the search attribute. Currently, the search attributes include node_name and node_type.

    Return type: text

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    gaussdb=# SELECT get_nodeinfo('node_type');
     get_nodeinfo 
    --------------
     DIS_CN
    (1 row)
    gaussdb=# SELECT get_nodeinfo('node_name');
     get_nodeinfo 
    --------------
     coordinator1
    (1 row)
    
  • get_schema_oid(cstring)

    Description: Returns the OID of the queried schema.

    Return type: OID

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT get_schema_oid('public');
     get_schema_oid
    ----------------
               2200
    (1 row)
    
  • pgxc_parse_clog(OUT xid int8, OUT nodename text, OUT status text)

    Description: Returns the status of all transactions in the current cluster.

    Return type: SETOF record

    Example:

    1
    2
    3
    4
    5
    6
    7
    gaussdb=# SELECT pgxc_parse_clog();
     pgxc_parse_clog
    ----------------
    (0,dn_6004_6005_6006,INPROGRESS)
    (1,dn_6004_6005_6006,COMMITTED)
    (2,dn_6004_6005_6006,INPROGRESS)
    (3 row)
    
  • pgxc_parse_clog(IN int2 bucketid, OUT xid int8, OUT nodename text, OUT status text)

    Description: Returns the statuses of all transactions with the specified bucket IDs in the current cluster. The input parameter is the bucket IDs of the hash bucket table. The value range is [–1,1023]. For an ordinary table, the value is –1.

    Return type: SETOF record

    Example:

    1
    2
    3
    4
    5
    6
    7
    gaussdb=# SELECT pgxc_parse_clog('-1');
     pgxc_parse_clog
    ----------------
    (0,dn_6004_6005_6006,INPROGRESS)
    (1,dn_6004_6005_6006,COMMITTED)
    (2,dn_6004_6005_6006,INPROGRESS)
    (3 row)
    
  • pgxc_prepared_xact()

    Description: Returns the list of transaction GIDs at the prepared stage in the cluster.

    Return type: set of text

    Example:

    1
    2
    3
    4
    gaussdb=# SELECT pgxc_prepared_xact();
     pgxc_prepared_xact
    --------------------          
    (0 row)
    
  • pgxc_xacts_iscommitted()

    Description: Returns the status of the transaction with the specified XID in the cluster. t indicates the committed state, f indicates the aborted state, and null indicates other states. To execute this function, you must have the sysadmin or monadmin permission.

    Return type: SETOF record

    Example:

    1
    2
    3
    4
    5
    6
    7
    8
    gaussdb=# SELECT pgxc_xacts_iscommitted(1);
     pgxc_xacts_iscommitted
    --------------------    
    (dn_6004_6005_6006,t)
    (cn_5001,t)
    (cn_5002,t)
    (dn_6001_6002_6003,t)      
    (4 row)
    
  • pgxc_total_memory_detail()

    Description: Displays the memory usage in the cluster. To execute this function, you must have the sysadmin or monadmin permission.

    If the GUC parameter enable_memory_limit is set to off, this function cannot be used.

    Return type: set of pv_total_memory_detail

    Example:

    1
    2
    3
    4
    5
    6
    7
    8
    gaussdb=# SELECT pgxc_total_memory_detail();
    pgxc_total_memory_detail
    --------------------    
    (dn_6004_6005_6006,max_process_memory,81920)
    (dn_6004_6005_6006,process_used_memory,72747)
    (dn_6004_6005_6006,max_dynamic_memory,12096)
    (dn_6004_6005_6006,dynamic_used_memory,1530)      
    (4 row)
    
  • pv_total_memory_detail()

    Description: Collects statistics on memory usage of the current database node in the unit of MB.

    If the GUC parameter enable_memory_limit is set to off, this function cannot be used.

    Return type: record

    Table 1 Return value description

    Name

    Type

    Description

    nodename

    text

    Node name

    memorytype

    text

    Memory type. The value must be one of the following:
    • max_process_memory: memory occupied by a GaussDB cluster instance
    • process_used_memory: memory occupied by a GaussDB thread
    • max_dynamic_memory: maximum dynamic memory
    • dynamic_used_memory: used dynamic memory
    • dynamic_peak_memory: dynamic peak memory
    • dynamic_used_shrctx: maximum dynamic shared memory context
    • dynamic_peak_shrctx: dynamic peak value of the shared memory context
    • max_shared_memory: maximum shared memory
    • shared_used_memory: used shared memory
    • max_sctpcomm_memory: maximum memory allowed for the communications library
    • sctpcomm_used_memory: memory used by the communications library
    • sctpcomm_peak_memory: memory peak of the communications library
    • other_used_memory: other used memory

    memorymbytes

    integer

    Size of allocated memory-typed memory

  • get_client_info()

    Description: Returns client information.

    Return type: record

Access Permission Query Functions

The DDL permissions, including ALTER, DROP, COMMENT, INDEX, and VACUUM, are inherent permissions implicitly owned by the owner.

The following access permission query function only indicates whether a user has a certain permission on an object. That is, the permission on the object recorded in the acl column of the system catalog is returned.

  • has_any_column_privilege(user, table, privilege)

    Description: Queries whether a specified user has permissions on any column of a table.

    Table 2 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    table

    text, oid

    Tables

    Table name or ID

    privilege

    text

    Permissions

    • SELECT: allows the SELECT statement to be executed on any column of a specified table.
    • INSERT: allows the INSERT statement to be executed on any column of a specified table.
    • UPDATE: allows the UPDATE statement to be executed on any column of a specified table.
    • REFERENCES: allows a foreign key constraint (not supported in distributed mode).
    • COMMENT: allows the COMMENT statement to be executed on any column of a specified table.

    Return type: Boolean

  • has_any_column_privilege(table, privilege)

    Description: Queries whether the current user has the permission to access any column of a table. For details about the valid parameter types, see Table 2.

    Return type: Boolean

    Note: 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 those of has_table_privilege, except that the desired access permission type must be some combination of SELECT, INSERT, UPDATE, or REFERENCES.

    Note that having any of these permissions at the table level indicates that the permission is implicitly granted for each column of the table. Therefore, has_any_column_privilege always returns true if has_table_privilege has the same parameters. But "success" is also returned if there is a column-level grant of the permission for at least one column.

  • has_column_privilege(user, table, column, privilege)

    Description: Specifies whether a specified user has the permission to access columns.

    Table 3 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    table

    text, oid

    Table name

    Table name or ID

    column

    text, smallint

    Column name

    Name or attribute number of a column

    privilege

    text

    Permissions

    • SELECT: allows the SELECT statement to be executed on specified columns of a table.
    • INSERT: allows the INSERT statement to be executed on specified columns of a table.
    • UPDATE: allows the UPDATE statement to be executed on specified columns of a table.
    • REFERENCES: allows a foreign key constraint (not supported in distributed mode).
    • COMMENT: allows the COMMENT statement to be executed on specified columns of a table.

    Return type: Boolean

  • has_column_privilege(table, column, privilege)

    Description: Specifies whether the current user has the permission to access columns. For details about the valid parameter types, see Table 3.

    Return type: Boolean

    has_column_privilege checks whether a user can access a column in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. Columns can be added either by name or by attribute number. The desired access permission type must be some combination of SELECT, INSERT, UPDATE, or REFERENCES.

    Note that having any of these permissions at the table level indicates that the permission is implicitly granted for each column of the table.

  • has_cek_privilege(user, cek, privilege)

    Description: Specifies whether a specified user has permissions on CEKs.

    Table 4 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    cek

    text, oid

    CEK

    Name or ID of a CEK

    privilege

    text

    Permission

    • USAGE: allows users to use the specified CEK.
    • DROP: allows users to delete the specified CEK.

    Return type: Boolean

  • has_cmk_privilege(user, cmk, privilege)

    Description: Specifies whether a specified user has permissions on CMKs.

    Table 5 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    cmk

    text, oid

    CMK

    Name or ID of the CMK

    privilege

    text

    Permission

    • USAGE: allows users to use the specified CMK.
    • DROP: allows users to delete the specified CMK.

    Return type: Boolean

  • has_database_privilege(user, database, privilege)

    Description: Specifies whether a specified user has permissions on databases.

    Table 6 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    database

    text, oid

    Database

    Database name or ID

    privilege

    text

    Permission

    • CREATE: For databases, allows new schemas to be created within the database.
    • TEMPORARY: allows users to create temporary tables when the database is used.
    • TEMP: allows users to create temporary tables when the database is used.
    • CONNECT: allows users to access specified databases.
    • ALTER: allows users to modify the attributes of a specified object.
    • DROP: allows users to delete a specified object.
    • COMMENT: allows users to define or modify comments of a specified object.

    Return type: Boolean

  • has_database_privilege(database, privilege)

    Description: Queries whether the current user has the permission to access a database. For details about the valid parameter types, see Table 6.

    Return type: Boolean

    Note: has_database_privilege checks whether a user can access a database in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. The desired access permission type must be some combination of CREATE, CONNECT, TEMPORARY, or TEMP (which is equivalent to TEMPORARY).

  • has_directory_privilege(user, directory, privilege)
    Table 7 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    directory

    text, oid

    Directory

    Directory name or OID

    privilege

    text

    Permission

    • READ: allows read operations on the directory.
    • WRITE: allows write operations on the directory.

    Description: Specifies whether a specified user has permissions on directories.

    Return type: Boolean

  • has_directory_privilege(directory, privilege)

    Description: Queries whether the current user has the permission to access a directory. For details about the valid parameter types, see Table 7.

    Return type: Boolean

  • has_foreign_data_wrapper_privilege(user, fdw, privilege)
    Table 8 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    fdw

    text, oid

    Foreign data wrapper

    Name or ID of the foreign data wrapper

    privilege

    text

    Permission

    USAGE: allows access to the foreign data wrapper.

    Description: Specifies whether a specified user has permissions on foreign data wrappers.

    Return type: Boolean

  • has_foreign_data_wrapper_privilege(fdw, privilege)

    Description: Queries whether the current user has permissions on foreign data wrappers. For details about the valid parameter types, see Table 8.

    Return type: Boolean

    Note: has_foreign_data_wrapper_privilege checks whether a user can access a foreign data wrapper in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. The desired access permission type must evaluate to USAGE.

  • has_function_privilege(user, function, privilege)
    Table 9 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    function

    text, oid

    Function

    Function name or ID

    privilege

    text

    Permission

    EXECUTE: allows users to use specified functions and the operators that are realized by the functions.

    • ALTER: allows users to modify the attributes of a specified object.
    • DROP: allows users to delete a specified object.
    • COMMENT: allows users to define or modify comments of a specified object.

    Description: Specifies whether a specified user has permissions on functions.

    Return type: Boolean

  • has_function_privilege(function, privilege)

    Description: Specifies whether the current user has permissions on functions. For details about valid parameter types, see Table 9.

    Return type: Boolean

    Note: has_function_privilege checks whether a user can access a function in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. When a function is specified by a text string rather than by an OID, the allowed input is the same as that for the regprocedure data type (see Object Identifier Types). The desired access permission type must be EXECUTE.

  • has_language_privilege(user, language, privilege)
    Table 10 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Username or ID

    language

    text, oid

    Language

    Language name or ID

    privilege

    text

    Permission

    USAG: allows users to specify a procedural language when creating a function.

    Description: Specifies whether a specified user has permissions on languages.

    Return type: Boolean

  • has_language_privilege(language, privilege)

    Description: Specifies whether the current user has permissions on languages. For details about valid parameter types, see Table 10.

    Return type: Boolean

    Note: has_language_privilege checks whether a user can access a procedural language in a particular way. Its parameter possibilities are analogous to those of 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 11 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Existing username or ID

    nodegroup

    text, oid

    Cluster node

    Existing cluster node

    privilege

    text

    Permission

    • USAGE: For sub-clusters, allows users who can access objects contained in the schema to access tables in the sub-cluster.
    • CREATE: For sub-clusters, allows users to create tables within the sub-cluster.
    • COMPUTE: allows elastic computing in the sub-cluster.
    • ALTER: allows users to modify the attributes of a specified object.
    • DROP: allows users to delete a specified object.
  • 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: Specifies whether a specified user has permissions on schemas.

    Return type: Boolean

  • has_schema_privilege(schema, privilege)

    Description: Specifies whether the current user has permissions on schemas.

    Return type: Boolean

    Note: has_schema_privilege checks whether a user can access a schema in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. The desired access permission type must be a combination among CREATE, USAGE, ALTER, DROP, and COMMENT. If the check type contains the CREATE permission and the checked schema is a schema with the same name as the user, the function returns TRUE only when the user has the OWNER permission for the schema due to the special constraint of the schema with the same name.

  • has_sequence_privilege(user, sequence, privilege)

    Description: Queries whether a specified user has permissions on sequences.

    Return type: Boolean

    Table 12 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name, oid

    Users

    Existing username or ID

    sequence

    text, oid

    Sequence

    Existing sequence name or ID

    privilege

    text

    Permission

    • USAGE: For sequences, allows users to use the nextval function.
    • SELECT: allows users to create a sequence.
    • UPDATE: allows users to execute the UPDATE statement.
    • ALTER: allows users to modify the attributes of a specified object.
    • DROP: allows users to delete a specified object.
    • COMMENT: allows users to define or modify comments of a specified object.
  • has_sequence_privilege(sequence, privilege)

    Description: Queries whether the current user has permissions on sequences.

    Return type: Boolean

  • has_server_privilege(user, server, privilege)

    Description: Specifies whether a specified user has permissions on foreign servers.

    Return type: Boolean

  • has_server_privilege(server, privilege)

    Description: Specifies whether the current user has permissions on foreign servers.

    Return type: Boolean

    Note: has_server_privilege checks whether a user can access a foreign server in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. The access permission type must be USAGE, ALTER, DROP, or COMMENT.

  • has_table_privilege(user, table, privilege)

    Description: Specifies whether a specified user has permissions on tables.

    Return type: Boolean

  • has_table_privilege(table, privilege)

    Description: Specifies whether the current user has permissions on tables.

    Return type: Boolean

    Note: has_table_privilege checks whether a user can access a table in a particular way. The user can be specified by name or by OID (pg_authid.oid), or be set to public which indicates public pseudo roles. If this parameter is omitted, current_user is used. The table can be specified by name or by OID. When it is specified by name, the name can be schema-qualified if necessary. If the desired access permission type is specified by a text string, the text string must be one of the values SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCESTRIGGER, ALTER, DROP, COMMENT, INDEX, or VACUUM. Optionally, WITH GRANT OPTION can be added to a permission type to test whether the permission is held with the grant option. Also, multiple permission types can be separated by commas (,), in which case the result will be true if any of the listed permissions is held.

    Example:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    gaussdb=# SELECT has_table_privilege('tpcds.web_site', 'select');
     has_table_privilege  
    --------------------- 
     t 
    (1 row)
    
    gaussdb=# 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: Specifies whether a specified user has permissions on tablespaces.

    Return type: Boolean

  • has_tablespace_privilege(tablespace, privilege)

    Description: Specifies whether the current user has permissions on tablespaces.

    Return type: Boolean

    Note: has_tablespace_privilege checks whether a user can access a tablespace in a particular way. Its parameter possibilities are analogous to those of has_table_privilege. The access permission type must be CREATE, ALTER, DROP, or COMMENT.

  • pg_has_role(user, role, privilege)

    Description: Specifies whether a specified user has permissions on roles.

    Return type: Boolean

  • pg_has_role(role, privilege)

    Description: Specifies whether the current user has permissions on roles.

    Return type: Boolean

    Note: pg_has_role checks whether a user can access a role in a particular way. Its parameter possibilities are analogous to those of has_table_privilege, except that public cannot be used as a username. The desired access permission type must be some combination of MEMBER or USAGE. MEMBER denotes direct or indirect membership in the role (that is, permission SET ROLE), while USAGE denotes the usage permission on the role that is available without the SET ROLE permission.

  • has_any_privilege(user, privilege)

    Description: Queries whether a specified user has certain ANY permission. If multiple permissions are queried at the same time, true is returned as long as one permission is obtained.

    Return type: Boolean

    Table 13 Parameter type description

    Parameter

    Valid Input Parameter Type

    Description

    Value Range

    user

    name

    Users

    Existing username

    privilege

    text

    ANY permission

    Available values:

    • CREATE ANY TABLE [WITH ADMIN OPTION]
    • ALTER ANY TABLE [WITH ADMIN OPTION]
    • DROP ANY TABLE [WITH ADMIN OPTION]
    • SELECT ANY TABLE [WITH ADMIN OPTION]
    • INSERT ANY TABLE [WITH ADMIN OPTION]
    • UPDATE ANY TABLE [WITH ADMIN OPTION]
    • DELETE ANY TABLE [WITH ADMIN OPTION]
    • CREATE ANY SEQUENCE [WITH ADMIN OPTION]
    • CREATE ANY INDEX [WITH ADMIN OPTION]
    • CREATE ANY FUNCTION [WITH ADMIN OPTION]
    • EXECUTE ANY FUNCTION [WITH ADMIN OPTION]
    • CREATE ANY TYPE [WITH ADMIN OPTION]

Schema Visibility Query Functions

Each function performs the visibility check on one type of database objects. For functions and operators, an object in the search path is visible if there is no object of the same name and parameter data type earlier in the path. For operator classes, both name and associated index access methods are considered.

All these functions require OIDs to identify the objects to be checked. If you want to test an object by name, it is convenient to use the OID alias type (regclass, regtype, regprocedure, regoperator, regconfig, or regdictionary).

For example, a table is said to be visible if the schema where the table is located 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. To list the names of all visible tables, run the following command:

1
gaussdb=# SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
  • pg_collation_is_visible(collation_oid)

    Description: Specifies whether the collation is visible in the search path.

    Return type: Boolean

  • pg_conversion_is_visible(conversion_oid)

    Description: Specifies whether the conversion is visible in the search path.

    Return type: Boolean

  • pg_function_is_visible(function_oid)

    Description: Specifies whether the function is visible in the search path.

    Return type: Boolean

  • pg_opclass_is_visible(opclass_oid)

    Description: Specifies whether the operator class is visible in the search path.

    Return type: Boolean

  • pg_operator_is_visible(operator_oid)

    Description: Specifies whether the operator is visible in the search path.

    Return type: Boolean

  • pg_opfamily_is_visible(opclass_oid)

    Description: Specifies whether the operator family is visible in the search path.

    Return type: Boolean

  • pg_table_is_visible(table_oid)

    Description: Specifies whether the table is visible in the search path.

    Return type: Boolean

  • pg_ts_config_is_visible(config_oid)

    Description: Specifies whether the text search configuration is visible in the search path.

    Return type: Boolean

  • pg_ts_dict_is_visible(dict_oid)

    Description: Specifies whether the text search dictionary is visible in the search path.

    Return type: Boolean

  • pg_ts_parser_is_visible(parser_oid)

    Description: Specifies whether the text search parser is visible in the search path.

    Return type: Boolean

  • pg_ts_template_is_visible(template_oid)

    Description: Specifies whether the text search template is visible in the search path.

    Return type: Boolean

  • pg_type_is_visible(type_oid)

    Description: Specifies whether the type (or domain) is visible in the search path.

    Return type: Boolean

System Catalog Information Functions

  • format_type(type_oid, typemod)

    Description: Obtains the SQL name of a data type.

    Return type: text

    Note: format_type returns the SQL name of a data type based on the OID of the data type and possible modifiers. If the specific modifier is unknown, pass NULL at the position of the modifier. Modifiers are generally meaningful only for data types with length restrictions. The SQL name returned by 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. Therefore, the actual storage length contains 4 bytes more than the customized length. In the following example, the SQL name returned by format_type is character varying(6), indicating the length of the varchar type is 6 bytes. Therefore, the actual storage length of the varchar type is 10 bytes.

    1
    2
    3
    4
    5
    gaussdb=# 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: Checks whether a role name with given OID exists.

    Return type: Boolean

    gaussdb=# select pg_check_authid(1);
    pg_check_authid
    -----------------
    f
    (1 row)
  • pg_describe_object(catalog_id, object_id, object_sub_id)

    Description: Obtains the description of a database object.

    Return type: text

    Note: pg_describe_object returns the description of a database object specified by a catalog OID, an object OID, and a (possibly zero) sub-object ID. This is useful to determine the identity of an object stored in the pg_depend catalog.

  • pg_get_constraintdef(constraint_oid)

    Description: Obtains definition of a constraint.

    Return type: text

  • pg_get_constraintdef(constraint_oid, pretty_bool)

    Description: Obtains definition of a constraint.

    Return type: text

    Note: pg_get_constraintdef and pg_get_indexdef respectively reconstruct the creation command for a constraint and an index.

  • pg_get_expr(pg_node_tree, relation_oid)

    Description: Decompiles the 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 the 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 of a column. This helps to check the content of system catalogs. If the expression contains keywords, specify the OID of the relationship that the keywords refer to as the second parameter; if no keywords are contained, use zero.

  • pg_get_functiondef(func_oid)

    Description: Obtains the definition of a function.

    Return type: text

    Example:
    gaussdb=# 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: Obtains argument list of function's definition (with default values).

    Return type: text

    Note: pg_get_function_arguments returns the parameter list of a function, in the form it would need to appear in CREATE FUNCTION.

  • pg_get_function_identity_arguments(func_oid)

    Description: Obtains the parameter list to identify a function (without default values).

    Return type: text

    Note: pg_get_function_identity_arguments returns the parameter 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: Obtains the RETURNS clause for a function.

    Return type: text

    Note: pg_get_function_result returns the appropriate RETURNS clause for the function.

  • pg_get_indexdef(index_oid)

    Description: Obtains the CREATE INDEX command for an index.

    Return type: text

    Example:
    gaussdb=# 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, dump_schema_only)

    Description: Obtains the CREATE INDEX command for indexes in dump scenarios. In the current version, the value of dump_schema_only does not affect the function output.

    Return type: text

    Example:
    gaussdb=# SELECT * FROM pg_get_indexdef(16416, true);
                                 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: Obtains the CREATE INDEX command for an index, or definition of just one index column when the value of column_no is not zero.

    Return type: text

    Example:
    gaussdb=# 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)
    gaussdb=# SELECT * FROM pg_get_indexdef(16416, 1, false);
     pg_get_indexdef 
    -----------------
     b
    (1 row)

    Note: pg_get_functiondef returns a complete CREATE OR REPLACE FUNCTION statement for a function.

  • pg_get_keywords()

    Description: Obtains the 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 keywords. 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_ruledef(rule_oid)

    Description: Obtains the CREATE RULE command for a rule.

    Return type: text

  • pg_get_ruledef(rule_oid, pretty_bool)

    Description: Obtains the CREATE RULE command for a rule.

    Return type: text

  • pg_get_userbyid(role_oid)

    Description: Obtains the role name with a 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

    gaussdb=# SELECT pg_check_authid(20);
    pg_check_authid
    -----------------
    f
    (1 row)
  • pg_get_viewdef(view_name)

    Description: Obtains the underlying SELECT command for a view.

    Return type: text

  • pg_get_viewdef(view_name, pretty_bool)

    Description: Obtains the underlying SELECT command for a view. Lines with columns are wrapped to 80 columns if pretty_bool is set to true.

    Return type: text

    Note: pg_get_viewdef reconstructs the SELECT query that defines a view. Most of these functions come in two forms. When the function has the pretty_bool parameter and the value is true, it can optionally "pretty-print" the result. The pretty-printed format is more readable. The other one is the default format which is more likely to be interpreted in the same way by future versions. Avoid using pretty-printed output for dump purposes. Passing false to the pretty-print parameter generates the same result as a variant without this parameter.

  • pg_get_viewdef(view_oid)

    Description: Obtains the underlying SELECT command for a view.

    Return type: text

  • pg_get_viewdef(view_oid, pretty_bool)

    Description: Obtains the underlying SELECT command for a view. Lines with columns are wrapped to 80 columns if pretty_bool is set to true.

    Return type: text

  • pg_get_viewdef(view_oid, wrap_column_int)

    Description: Obtains the underlying SELECT command for a view. Lines with columns are wrapped to the specified number of columns and printing is implicit.

    Return type: text

  • pg_get_tabledef(table_oid)

    Description: Obtains the definition of a table based on table_oid.

    Return type: text

    Example:
    gaussdb=# 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;                                                       +
     ILM Security Policies:                                                 +
        POLICY "p4" TABLE                                                   +
          ROW STORE COMPRESS ADVANCED ROW AFTER 1 DAYS OF NO MODIFICATION   +    
          STATUS: ENABLED  DELETED: NO                                      +
    (1 row)
  • pg_get_tabledef(table_name)

    Description: Obtains the definition of a table based on table_name.

    Return type: text

    Example:
    gaussdb=# 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;                                                       +
     ILM Security Policies:                                                 +
        POLICY "p4" TABLE                                                   +
          ROW STORE COMPRESS ADVANCED ROW AFTER 1 DAYS OF NO MODIFICATION   +  
          STATUS: ENABLED  DELETED: NO                                      +
    (1 row)

    Note: pg_get_tabledef reconstructs the CREATE statement of the definition of the table, including the table definition, index information, comments, and ILM policy. You need to create the group, schema, tablespace, and server information on which the table object depends.

  • pg_options_to_table(reloptions)

    Description: Obtains 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 pg_class.reloptions or pg_attribute.attoptions is passed.

  • pg_tablespace_databases(tablespace_oid)

    Description: Obtains 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 checked. It returns the set of OIDs of databases that have objects stored in the tablespace. If this function returns any rows of data, the tablespace is not empty and cannot be dropped. To display the specific objects in the tablespace, you need to connect to the databases identified by pg_tablespace_databases and query their pg_class catalogs.

  • pg_tablespace_location(tablespace_oid)

    Description: Obtains the path in the file system that this tablespace is located in.

    Return type: text

  • pg_typeof(any)

    Description: Obtains 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. It is declared that the function returns 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:

     1
     2
     3
     4
     5
     6
     7
     8
     9
    10
    11
    gaussdb=# SELECT pg_typeof(33);
     pg_typeof 
    -----------
     integer
    (1 row)
    
    gaussdb=# SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
     typlen 
    --------
          4
    (1 row)
    
  • collation for (any)

    Description: Obtains 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:

    1
    2
    3
    4
    5
    gaussdb=# 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 parameter expression, then a null value is returned. If the argument is not of a collatable data type, then an error message is displayed.

  • getdistributekey(table_name)

    Description: Gets a distribution key for a hash table.

    Return type: text

    Example:

    1
    2
    3
    4
    5
    gaussdb=# SELECT getdistributekey('item');
     getdistributekey 
    ------------------
     i_item_sk
    (1 row)
    
  • pg_extension_update_paths(name)

    Description: Returns the version update path of the specified extension. This function can be called only by the system administrator.

    Return type: text (source text), text (target text), text (path text)

  • pg_get_serial_sequence(tablename, colname)

    Description: Obtains the sequence of the corresponding table name and column name.

    Return type: text

    Example:
    gaussdb=# 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: int16, int16, int16, int16, Boolean

    Example:
    gaussdb=# 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:
    gaussdb=# 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)
  • gs_get_index_status(schema_name, index_name)

    Description: Obtains the index status information on all nodes, including whether an index can be inserted and whether an index is available. This function is mainly used to check the index status during online index creation or when the index creation fails. The return values include node_name, indisready, and indisvalid. Only when indisready and indisvalid of indexes on all nodes are set to true and the index state is not changed to unusable, the current index is available.

    Return type: text, Boolean, Boolean

    Example:
    gaussdb=# SELECT * FROM gs_get_index_status('public', 'index1');
       node_name    | indisready | indisvalid
    ----------------+------------+-----------
     datanode1      | t          | t
     datanode2      | t          | t
     coordinator1   | t          | t
    (3 row)

Comment Information Functions

  • col_description(table_oid, column_number)

    Description: Obtains the 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: Obtains the 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 system catalog to which it belongs. 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 OID.

    obj_description cannot be used for table columns since columns do not have OIDs of their own.

  • obj_description(object_oid)

    Description: Obtains the comment for a database object.

    Return type: text

  • shobj_description(object_oid, catalog_name)

    Description: Obtains the comment for a shared database object.

    Return type: text

    Note: shobj_description is used just like obj_description, except that the former is used for shared objects. Some system catalogs are global to all databases in the cluster, and the comments for objects in them are stored globally as well.

XIDs and Snapshots

Internal XIDs are 64 bits. txid_snapshot, data type used by these functions, stores information about XID visibility at a particular moment in time. Table 14 describes the components.
Table 14 Snapshot components

Name

Description

xmin

Earliest XID (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 greater than or equal to xmin and less than xmax and that is not in this list was already completed at the time of the snapshot, and is either visible or rolled back according to its commit status. The list does not include txids of subtransactions.

The textual representation of txid_snapshot is xmin:xmax:xip_list.

For example, 10:20:10,14,15 means xmin=10, xmax=20, xip_list=10, 14, 15.

The following functions provide server transaction information in an exportable form. These functions are mainly used to determine which transactions were committed between two snapshots.

  • pgxc_is_committed(transaction_id)

    Description: Specifies whether the given XID is committed or ignored. NULL indicates the unknown status (it can be running, ready, frozen, or other status). In maintenance mode (when the GUC parameter xc_maintenance_mode is set to on), the statuses of all transactions with the specified bucket IDs and ordinary tables are traversed. If a status conflict occurs, for example, the status of the same transaction is committed in bucket 1 and rolled back in bucket 2, an error is reported. Exercise caution when enabling the mode. It is used by maintenance engineers for troubleshooting. Common users should not use the mode.

    Return type: Boolean

  • pgxc_is_committed(transaction_id, bucketid)

    Description: Commits or ignores the given transaction (gxid) if bucketid is specified. NULL indicates that the status is unknown (running, ready, or frozen). bucketid is the physical bucket ID of the hash bucket table. The value is –1 for an ordinary table. In maintenance mode (when the GUC parameter xc_maintenance_mode is set to on), if bucketid is set to –1, the statuses of all transactions with the specified bucket IDs and ordinary tables are traversed. If a status conflict occurs, for example, the status of the same transaction is committed in bucket 1 and rolled back in bucket 2, an error is reported. Exercise caution when enabling the mode. It is used by maintenance engineers for troubleshooting. Common users should not use the mode.

    Return type: Boolean

  • txid_current()

    Description: Obtains the current XID.

    Return type: bigint

  • gs_txid_oldestxmin()

    Description: Obtains the minimum XID (specified by oldesxmin).

    Return type: bigint

  • txid_current_snapshot()

    Description: Obtains the current snapshot.

    Return type: txid_snapshot

  • txid_snapshot_xip(txid_snapshot)

    Description: Obtains in-progress XIDs in a snapshot.

    Return type: setof bigint

  • txid_snapshot_xmax(txid_snapshot)

    Description: Obtains xmax of snapshots.

    Return type: bigint

  • txid_snapshot_xmin(txid_snapshot)

    Description: Obtains xmin of snapshots.

    Return type: bigint

  • txid_visible_in_snapshot(bigint, txid_snapshot)

    Description: Specifies whether the XID is visible in a snapshot (do not use subtransaction IDs).

    Return type: Boolean

  • get_local_prepared_xact()

    Description: Obtains the two-phase residual transaction information of the current node, including the XID, GID of the two-phase transaction, prepared time, owner OID, database OID, and node name of the current node.

    Return type: xid, text, timestamptz, oid, text

  • get_remote_prepared_xacts()

    Description: Obtains the two-phase residual transaction information of all remote nodes, including the XID, GID of the two-phase transaction, prepared time, owner name, database name, and node name.

    Return type: xid, text, timestamptz, 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 cleaning. In other situations, false is returned.

    Return type: Boolean

  • pgxc_stat_get_wal_senders()

    Description: Returns the sent logs of all primary DNs and the received logs of their corresponding standby DNs in the cluster. Only users with the system admin or monitor admin permission can use this function.

    For details about the return values, see Table 15.
    Table 15 pgxc_stat_get_wal_senders parameters

    Column

    Description

    nodename

    Instance name.

    sender_pid

    PID of the thread for sending logs.

    local_role

    Instance role.

    peer_role

    Role of the instance on the receiver.

    peer_state

    Status of the instance on the receiver.

    state

    Synchronization status between instances.

    sender_sent_location

    Location where the sender sends logs.

    sender_write_location

    Location where the sender writes logs.

    sender_flush_location

    Location where the sender flushes logs to disks.

    sender_replay_location

    Location of the instance logs. If the DN is a primary DN, the location is the value of sender_flush_location. Otherwise, the location where the current instance log is replayed is used.

    receiver_received_location

    Location where the receiver receives logs.

    receiver_write_location

    Location where the receiver writes logs.

    receiver_flush_location

    Location where the receiver flushes logs to disks.

    receiver_replay_location

    Location where the receiver replays logs.

  • pgxc_stat_get_wal_senders_status()

    Description: Returns the receiving status of transaction logs on all nodes. Only users with the system admin or monitor admin permission can use this function.

    For details about the return values, see Table 16.

    Table 16 pgxc_stat_get_wal_senders_status 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

  • gs_get_next_xid_csn()

    Description: Returns the values of next_xid and next_csn on all nodes globally.

    For details about the return values, see Table 17.

    Table 17 gs_get_next_xid_csn parameters

    Column

    Description

    nodename

    Node name

    next_xid

    ID of the next transaction on the current node.

    next_csn

    Next CSN of the current node.

  • pg_control_system()

    Description: Returns the status of the system control file.

    Return type: SETOF record

  • pg_control_checkpoint()

    Description: Returns the system checkpoint status

    Return type: SETOF record

  • get_prepared_pending_xid()

    Description: Returns nextxid when restoration is complete.

    Parameter: nan

    Return type: text

  • pg_clean_region_info()

    Description: Clears the region map.

    Parameter: nan

    Return type: character varying

  • pg_get_replication_slot_name()

    Description: Obtains the slot name.

    Parameter: nan

    Return type: text

  • pg_get_running_xacts()

    Description: Obtains running xact.

    Parameter: nan

    Return type: handle integer, gxid xid, state tinyint, node text, xmin xid, vacuum boolean, timeline bigint, prepare_xid xid, pid bigint, next_xid xid

  • pg_get_variable_info()

    Description: Obtains the shared memory variable cache.

    Parameter: nan

    Return type: node_name text, nextOid oid, nextXid xid, oldestXid xid, xidVacLimit xid, oldestXidDB oid, lastExtendCSNLogpage xid, startExtendCSNLogpage xid, nextCommitSeqNo xid, latestCompletedXid xid, and startupMaxXid xid

  • pg_get_xidlimit()

    Description: Obtains XID information from the shared memory.

    Parameter: nan

    Return type: nextXid xid, oldestXid xid, xidVacLimit xid, xidWarnLimit xid, xidStopLimit xid, xidWrapLimit xid, oldestXidDB oid

  • pg_relation_compression_ratio()

    Description: Queries the compression rate of a table. By default, 1.0 is returned.

    Parameter: text

    Return type: real

  • pg_relation_with_compression()

    Description: Specifies whether a table is compressed.

    Parameter: text

    Return type: Boolean

  • pg_stat_file_recursive()

    Description: Lists all files in a path.

    Parameter: location text

    Return type: path text, filename text, size bigint, isdir boolean

  • pg_stat_get_activity_for_temptable()

    Description: Returns records of backend threads related to the temporary table.

    Parameter: nan

    Return type: datid oid, timelineid integer, tempid integer, and sessionid bigint

  • pg_stat_get_activity_ng()

    Description: Returns records of backend threads related to nodegroup.

    Parameter: pid bigint

    Return type: datid oid, pid bigint, sessionid bigint, and node_group text

  • pg_stat_get_cgroup_info()

    Description: Returns Cgroup information.

    Parameter: nan

    Return type: cgroup_name text, percent integer, usage_percent integer, shares bigint, usage bigint, cpuset text, relpath text, valid text, node_group text

  • pg_stat_get_realtime_info_internal()

    Description: Returns real-time information. Currently, this API is unavailable. FailedToGetSessionInfo is returned.

    Parameter: oid, oid, bigint, cstring, oid

    Return type: text

  • pg_stat_get_wlm_session_iostat_info()

    Description: Returns the session load I/O information.

    Parameter: nan

    Return type: threadid bigint, maxcurr_iops integer, mincurr_iops integer, maxpeak_iops integer, minpeak_iops integer, iops_limits integer, io_priority integer, and curr_io_limits integer

  • pg_test_err_contain_err()

    Description: Tests the error type and return information.

    Parameter: integer

    Return type: void

  • pv_session_memory_detail_tp()

    Description: Returns the memory usage of the session. For details, see pv_session_memory_detail.

    Parameter: nan

    Return type: sessid text, sesstype text, contextname text, level smallint, parent text, totalsize bigint, freesize bigint, usedsize bigint

  • gs_get_table_distribution()

    Description: Returns the distribution of table data on each DN.

    Parameter: table_name text, schema_name text

    Return type: text

  • pv_builtin_functions()

    Description: Displays information about all built-in system functions.

    Parameter: nan

    Return type: proname name, pronamespace oid, proowner oid, prolang oid, procost real, prorows real, provariadic oid, protransform regproc, proisagg boolean, proiswindow boolean, prosecdef boolean, proleakproof boolean, proisstrict boolean, proretset boolean, provolatile "char", pronargs smallint, pronargdefaults smallint, prorettype oid, proargtypes oidvector, proallargtypes integer[], proargmodes "char"[], proargnames text[], proargdefaults pg_node_tree, prosrc text, probin text, proconfig text[], proacl aclitem[], prodefaultargpos int2vector, fencedmode boolean, proshippable boolean, propackage boolean, oid oid

  • pv_thread_memory_detail()

    Description: Returns the memory information of each thread.

    Parameter: nan

    Return type: threadid text, tid bigint, thrdtype text, contextname text, level smallint, parent text, totalsize bigint, freesize bigint, usedsize bigint

  • pg_shared_memory_detail()

    Description: Returns usage information about all generated shared memory contexts. For details about each column, see SHARED_MEMORY_DETAIL.

    Parameter: nan

    Return type: contextname text, level smallint, parent text, totalsize bigint, freesize bigint, usedsize bigint

  • pgxc_get_running_xacts()

    Description: Returns information about running transactions on each node in the cluster. The field content is the same as that in PGXC_RUNNING_XACTS. Only users with the system admin or monitor admin permission can view the information.

    Parameter: nan

    Return type: setof record

  • pgxc_snapshot_status()

    Description: Returns the status of key memory information in the GTM in GTM mode for fault locating. GTM-Free and GTM-Lite do not support this function.

    Parameter: nan

    Return type: xmin xid, xmax xid, xcnt int, oldestxmin xid, next_xid xid, timeline int, active_thread_num int, max_active_thread_num int, snapshot_num int, snapshot_totalsize bigint

    For details about the return values, see Table 18.

    Table 18 get_gtm_lite_status return parameters

    Column

    Description

    xmin

    Minimum active XID in the GTM.

    xmax

    Largest XID committed in the GTM plus 1. Transactions whose IDs are greater than or equal to this value are active.

    xcnt

    Number of active transactions in the GTM.

    oldestxmin

    ID of the earliest accessed transaction in the GTM.

    next_xid

    ID of the next transaction allocated by the GTM.

    timeline

    Current time line in the GTM.

    active_thread_num

    Number of active worker threads in the GTM.

    max_active_thread_num

    Peak number of worker threads in the GTM within one minute.

    snapshot_num

    Number of snapshots delivered by the GTM within one minute.

    snapshot_totalsize

    Total size of snapshots delivered by the GTM within one minute.

  • get_gtm_lite_status()

    Description: Returns the backup XID and CSN in the GTM for fault locating. This system function is not supported in GTM-Free mode.

    For details about the return values, see Table 19.
    Table 19 get_gtm_lite_status return parameters

    Column

    Description

    backup_xid

    Backup XID in the GTM.

    csn

    Latest CSN issued by the GTM.

  • adm_hist_snapshot_func()

    Description: Returns information about the snapshot execution time. To access this function, set the enable_wdr_snapshot parameter to on and obtain the permission to access the snapshot schema, snapshot table, and tables_snap_timestamp tables.

    Parameter: nan

    Return type: snap_id bigint, dbid oid, begin_interval_time timestamp(3), end_interval_time timestamp(3), flush_elapsed interval day(5) to second(1), begin_interval_time_tz timestamp(3) with time zone, end_interval_time_tz timestamp(3) with time zone

  • global_sql_patch_func()

    Description: SQL patch information on each global node, which is used to return the result of the global_sql_patch view.

    For details about the return values, see Table 20.

    Table 20 global_sql_patch_func return parameters

    Name

    Type

    Description

    node_name

    text

    Name of the node where the SQL patch is located.

    patch_name

    name

    Patch name.

    unique_sql_id

    bigint

    Global unique query ID.

    owner

    oid

    ID of the user who creates the patch.

    enable

    boolean

    Determines whether the patch takes effect.

    status

    "char"

    Patch status (reserved field).

    abort

    boolean

    Determines whether the value is AbortHint.

    hint_string

    text

    Hint text.

    description

    text

    Patch description.

    parent_unique_sql_id

    bigint

    Globally unique ID of the outer statement of the SQL statement for which the patch takes effect. The value of this parameter is 0 for statements outside a stored procedure. For statements inside the stored procedure, the value of this parameter is the globally unique ID of the statement that calls the stored procedure.

  • gs_get_current_version()

    Description: Returns the current compilation mode based on the current compilation macro. 'M' is returned.

    Parameter: nan

    Return type: char

  • gs_get_kernel_info()

    Description: Global transaction information on each primary CN and DN.

    For details about the return values, see Table 21.

    Table 21 gs_get_kernel_info parameter description

    Name

    Type

    Description

    node_name

    text

    Node name.

    module

    text

    Module name, including:

    • XACT (transaction module)
    • STANDBY (standby module)
    • UNDO (undo module)
    • HOTPATH (hot patch module)

    name

    text

    Name of the key data in the memory state, including:

    • startup_max_xid (maximum XID when a thread is started)
    • recent_local_xmin (minimum XID of a local active transaction) recent_global_xmin (minimum XID of a global active transaction)
    • standby_xmin (minimum XID of an active transaction on the standby node)
    • standby_redo_cleanup_xmin (minimum XID of cleanup logs during redo on the standby node)
    • standby_redo_cleanup_xmin_lsn (LSN of the minimum XID of cleanup logs during redo on the standby node)
    • local_csn_min (minimum CSN of a local active transaction)
    • replication_slot_xmin (minimum XID of a replication slot)
    • replication_slot_catalog_xmin (minimum XID of a catalog replication slot)
    • global_recycle_xid (minimum XID of a global undo recycling transaction)
    • global_frozen_xid (minimum XID of a globally frozen transaction)
    • recent_xmin (minimum XID of active transactions in the current session)
    • next_csn (CSN of the next transaction)
    • hotpatch_additional_info (reserved column for hot patches)
    • stmt_session_discard_records (data volume discarded by full SQL statements due to full slots supported by the kernel)
    • stmt_shm_flush_discard_records (data volume discarded by full SQL statements due to full ringbuf supported by the kernel)

    value

    text

    Value of the key data in the memory state.

    Example:

    gaussdb=# SELECT * FROM gs_get_kernel_info();
      node_name   | module  |             name              |  value  
    --------------+---------+-------------------------------+---------
     coordinator1 | XACT    | startup_max_xid               | 16488
     coordinator1 | XACT    | recent_local_xmin             | 16504
     coordinator1 | XACT    | recent_global_xmin            | 16503
     coordinator1 | STANDBY | standby_xmin                  | 0
     coordinator1 | STANDBY | standby_redo_cleanup_xmin     | 0
     coordinator1 | STANDBY | standby_redo_cleanup_xmin_lsn | 0/0
     coordinator1 | XACT    | local_csn_min                 | 6014225
     coordinator1 | XACT    | replication_slot_xmin         | 0
     coordinator1 | XACT    | replication_slot_catalog_xmin | 0
     coordinator1 | UNDO    | global_recycle_xid            | 16501
     coordinator1 | XACT    | global_frozen_xid             | 0
     coordinator1 | XACT    | recent_xmin                   | 16504
     coordinator1 | XACT    | next_csn                      | 6014226
     coordinator1 | HOTPATH | hotpatch_additional_info      | 
     coordinator1 | FULL_SQL| stmt_session_discard_records  | 0
     coordinator1 | FULL_SQL| stmt_shm_flush_discard_records| 0
     datanode1    | XACT    | startup_max_xid               | 16488
     datanode1    | XACT    | recent_local_xmin             | 15805
     datanode1    | XACT    | recent_global_xmin            | 15805
     datanode1    | STANDBY | standby_xmin                  | 0
     datanode1    | STANDBY | standby_redo_cleanup_xmin     | 0
     datanode1    | STANDBY | standby_redo_cleanup_xmin_lsn | 0/0
     datanode1    | XACT    | local_csn_min                 | 6014225
     datanode1    | XACT    | replication_slot_xmin         | 0
     datanode1    | XACT    | replication_slot_catalog_xmin | 0
     datanode1    | UNDO    | global_recycle_xid            | 15805
     datanode1    | XACT    | global_frozen_xid             | 0
     datanode1    | XACT    | recent_xmin                   | 15805
     datanode1    | XACT    | next_csn                      | 6014226
     datanode1    | HOTPATH | hotpatch_additional_info      | 
     datanode1    | FULL_SQL| stmt_session_discard_records  | 0
     datanode1    | FULL_SQL| stmt_shm_flush_discard_records| 0
    (32 row)