System Information Functions
Session Information Functions
current_catalog
Description: Name of the current database (called “catalog” in the SQL standard)
Return type: name
Example:
openGauss=# SELECT current_catalog; current_database ------------------ openGauss (1 row)
current_database()
Description: Name of the current database
Return type: name
Example:
openGauss=# SELECT current_database(); current_database ------------------ openGauss (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:
openGauss=# SELECT current_query(); current_query ------------------------- SELECT current_query(); (1 row)
current_schema[()]
Description: Name of current schema
Return type: name
Example:
openGauss=# 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:
openGauss=# 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:
openGauss=# 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:
openGauss=# SELECT definer_current_user(); definer_current_user ---------------------- omm (1 row)
pg_current_sessionid()
Description: Session ID of the current execution context
Return type: text
Example:
openGauss=# 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 the current execution context
Return type: text
Example:
openGauss=# 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
openGauss=# SELECT pg_current_userid(); pg_current_userid ------------------- 10 (1 row)
working_version_num()
Description: Returns a version number regarding system compatibility.
Return type: int
Example:
openGauss=# SELECT working_version_num(); working_version_num --------------------- 92231 (1 row)
tablespace_oid_name()
Description: Queries the tablespace name based on the tablespace OID.
Return type: text
Example:
openGauss=# 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:
openGauss=# 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:
openGauss=# 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:
openGauss=# 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:
openGauss=# SELECT inet_server_port(); inet_server_port ------------------ 8000 (1 row)
pg_backend_pid()
Description: Process ID of the server process attached to the current session
Return type: bigint
Example:
openGauss=# 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 with time zone when the server configuration files were last loaded.
Return type: timestamp with time zone
Example:
openGauss=# 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:
openGauss=# 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: Specifies whether the schema is the temporary schema of another session.
Return type: Boolean
Example:
openGauss=# 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:
openGauss=# 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:
openGauss=# 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 for a rule.
Return type: text
Example:
openGauss=# 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 gs_session_stat).
Return type: int8
Example:
openGauss=# select sessionid2pid(sessid::cstring) from gs_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:
openGauss=# SELECT session_context('USERENV', 'CURRENT_SCHEMA'); session_context ------------------ public (1 row)
pg_trigger_depth()
Description: Current nesting level of triggers
Return type: int
Example:
openGauss=# SELECT pg_trigger_depth(); pg_trigger_depth ------------------ 0 (1 row)
session_user
Description: Session user name
Return type: name
Example:
openGauss=# 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:
openGauss=# SELECT user; current_user -------------- omm (1 row)
getpgusername()
Description: Obtains the database username.
Return type: name
Example:
openGauss=# select getpgusername(); getpgusername --------------- GaussDB_userna (1 row)
getdatabaseencoding()
Description: Obtains the database encoding mode.
Return type: name
Example:
openGauss=# select getdatabaseencoding(); getdatabaseencoding --------------------- SQL_ASCII (1 row)
version()
Description: Version information. version returns a string describing a server's version.
Return type: text
Example:
openGauss=# select version(); version ------------------------------------------------------------------------------------------------------------------------------------------------------------- (openGauss x.x.x build fab4f5ea) compiled at 2021-10-24 11:58:22 commit 3086 last mr 6592 release (1 row)
opengauss_version()
Description: openGauss version information
Return type: text
Example:
openGauss=# select opengauss_version(); opengauss_version ------------------- 2.0.0 (1 row)
gs_deployment()
Description: Information about the deployment mode of the current system
Return type: text
Example:
openGauss=# select gs_deployment(); gs_deployment ----------------------- OpenSourceCentralized (1 row)
get_hostname()
Description: Returns the host name of the current node.
Return type: text
Example:
openGauss=# SELECT get_hostname(); get_hostname -------------- linux-user (1 row)
get_nodename()
Description: Returns the name of the current node.
Return type: text
Example:
openGauss=# SELECT get_nodename(); get_nodename -------------- datanode1 (1 row)
get_schema_oid(cstring)
Description: Returns the OID of the queried schema.
Return type: oid
Example:
openGauss=# SELECT get_schema_oid('public'); get_schema_oid ---------------- 2200 (1 row)
get_client_info()
Description: Returns client information.
Return type: record
Access privilege inquiry function
The DDL permissions, including ALTER, DROP, COMMENT, INDEX and VACUUM, are inherent permissions implicitly owned by the owner.
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
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.
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, COMMENT 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: Specifies whether a specified user has permission for columns.
Table 2 Parameter type description
Return type: Boolean
has_column_privilege(table, column, privilege)
Description: Specifies whether the current user has permission to access columns. For details about the valid parameter types, see Table 2.
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, COMMENT 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: Specifies whether a specified user has permission for CEKs. The parameters are described as follows:
Table 3 Parameter type description
Return type: Boolean
has_cmk_privilege(user, cmk, privilege)
Description: Specifies whether a specified user has permission for CMKs. The parameters are described as follows:
Table 4 Parameter type description
Return type: Boolean
has_database_privilege(user, database, privilege)
Description: Specifies whether a specified user has permission for databases. The parameters are described as follows:
Table 5 Parameter type description
Return type: Boolean
has_database_privilege(database, privilege)
Description: Specifies whether the current user has permission to access a database. For details about the valid parameter types, see Table 5.
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 be some combination of CREATE, CONNECT, TEMPORARY, ALTER, DROP, COMMENT or TEMP (which is equivalent to TEMPORARY).
has_directory_privilege(user, directory, privilege)
Description: Specifies whether a specified user has permission for directories.
Table 6 Parameter type description
Return type: Boolean
has_directory_privilege(directory, privilege)
Description: Specifies whether the current user has permission to access a directory. For details about the valid parameter types, see Table 6.
Return type: Boolean
has_foreign_data_wrapper_privilege(user, fdw, privilege)
Description: Specifies whether a specified user has permission for foreign-data wrappers.
Table 7 Parameter type description
Return type: Boolean
has_foreign_data_wrapper_privilege(fdw, privilege)
Description: Specifies whether the current user has permission for foreign-data wrappers. For details about the valid parameter types, see Table 7.
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: Specifies whether a specified user has permission for functions.
Table 8 Parameter type description
Return type: Boolean
has_function_privilege(function, privilege)
Description: Specifies whether the current user has permission for functions. For details about the valid parameter types, see Table 8.
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 OID Types). The access permission type must be EXECUTE, ALTER, DROP, or COMMENT.
has_language_privilege(user, language, privilege)
Description: Specifies whether a specified user has permission for languages.
Table 9 Parameter type description
Return type: Boolean
has_language_privilege(language, privilege)
Description: Specifies whether the current user has permission for languages. For details about the valid parameter types, see Table 9.
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 database node.
Return type: Boolean
Table 10 Parameter type description
has_nodegroup_privilege(nodegroup, privilege)
Description: Checks whether a user has permission to access a database node. The parameter is similar to has_table_privilege. The access permission type must be USAGE, CREATE, COMPUTE, ALTER, or CROP.
Return type: Boolean
has_schema_privilege(user, schema, privilege)
Description: Specifies whether a specified user has permission for schemas.
Return type: Boolean
has_schema_privilege(schema, privilege)
Description: Specifies whether the current user has permission for schemas.
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 be some combination of CREATE, USAGE, ALTER, DROP or COMMENT.
has_server_privilege(user, server, privilege)
Description: Specifies whether a specified user has permission for foreign servers.
Return type: Boolean
has_server_privilege(server, privilege)
Description: Specifies whether the current user has permission for foreign servers.
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 access permission type must be USAGE, ALTER, DROP, or COMMENT.
has_table_privilege(user, table, privilege)
Description: Specifies whether a specified user has permission for tables.
Return type: Boolean
has_table_privilege(table, privilege)
Description: Specifies whether the current user has permission for tables.
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 it is specified 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, TRIGGER, 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 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:
openGauss=# SELECT has_table_privilege('tpcds.web_site', 'select'); has_table_privilege --------------------- t (1 row) openGauss=# 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 permission for tablespaces.
Return type: Boolean
has_tablespace_privilege(tablespace, privilege)
Description: Specifies whether the current user has permission for tablespaces.
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 access permission type must be CREATE, ALTER, DROP, or COMMENT.
pg_has_role(user, role, privilege)
Description: Specifies whether a specified user has permission for roles.
Return type: Boolean
pg_has_role(role, privilege)
Description: Specifies whether the current user has permission for roles.
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.
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 11 Parameter type description
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 parameter data type 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:
openGauss=# 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 search path.
Return type: Boolean
pg_conversion_is_visible(conversion_oid)
Description: Specifies whether the conversion is visible in search path.
Return type: Boolean
pg_function_is_visible(function_oid)
Description: Specifies whether the function is visible in search path.
Return type: Boolean
pg_opclass_is_visible(opclass_oid)
Description: Specifies whether the operator class is visible in search path.
Return type: Boolean
pg_operator_is_visible(operator_oid)
Description: Specifies whether the operator is visible in search path.
Return type: Boolean
pg_opfamily_is_visible(opclass_oid)
Description: Specifies whether the operator family is visible in search path.
Return type: Boolean
pg_table_is_visible(table_oid)
Description: Specifies whether the table is visible in search path.
Return type: Boolean
pg_ts_config_is_visible(config_oid)
Description: Specifies whether the text search configuration is visible in search path.
Return type: Boolean
pg_ts_dict_is_visible(dict_oid)
Description: Specifies whether the text search dictionary is visible in search path.
Return type: Boolean
pg_ts_parser_is_visible(parser_oid)
Description: Specifies whether the text search parser is visible in search path.
Return type: Boolean
pg_ts_template_is_visible(template_oid)
Description: Specifies whether the text search template is visible in search path.
Return type: Boolean
pg_type_is_visible(type_oid)
Description: Specifies whether the type (or domain) is visible in 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 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.
openGauss=# SELECT format_type((SELECT oid FROM pg_type WHERE typname='varchar'), 10); format_type ---------------------- character varying(6) (1 row)
getdistributekey(table_name)
Description: Obtains a distribution column for a hash table. Distribution is not supported in a standalone system and the return value of this function is empty.
pg_check_authid(role_oid)
Description: Checks whether a role name with a given OID exists.
Return type: Boolean
Example:
openGauss=# 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 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: Obtains the definition of a constraint.
Return type: text
pg_get_constraintdef(constraint_oid, pretty_bool)
Description: Obtains the 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: Obtains the definition of a function.
Return type: text
Example:
openGauss=# 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 the parameter list of the 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 within 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:
openGauss=# 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. For an interval partitioned table that contains a local index, if dump_schema_only is set to true, the returned index creation statement does not contain the local index information of the automatically created partition. If dump_schema_only is set to false, the returned index creation statement contains the local index information of the automatically created partition. For a non-interval partitioned table or an interval partitioned table that does not contain a local index, the value of dump_schema_only does not affect the returned result of the function.
Return type: text
Example:
openGauss=# CREATE TABLE sales openGauss-# (prod_id NUMBER(6), openGauss(# cust_id NUMBER, openGauss(# time_id DATE, openGauss(# channel_id CHAR(1), openGauss(# promo_id NUMBER(6), openGauss(# quantity_sold NUMBER(3), openGauss(# amount_sold NUMBER(10,2) openGauss(# ) PARTITION BY RANGE( time_id) INTERVAL('1 day') openGauss-# openGauss-# ( openGauss(# partition p1 VALUES LESS THAN ('2019-02-01 00:00:00'), openGauss(# partition p2 VALUES LESS THAN ('2019-02-02 00:00:00') openGauss(# ); CREATE TABLE openGauss=# create index index_sales on sales(prod_id) local (PARTITION idx_p1 ,PARTITION idx_p2); CREATE INDEX openGauss=#-- If the data to be inserted does not match any partition, create a partition and insert the data into the new partition. openGauss=# INSERT INTO sales VALUES(1, 12, '2019-02-05 00:00:00', 'a', 1, 1, 1); INSERT 0 1 openGauss=# select oid from pg_class where relname = 'index_sales'; oid ------- 24632 (1 row) openGauss=# select * from pg_get_indexdef(24632, true); pg_get_indexdef -------------------------------------------------------------------------------------------------------------------------- CREATE INDEX index_sales ON sales USING btree (prod_id) LOCAL(PARTITION idx_p1, PARTITION idx_p2) TABLESPACE pg_default (1 row) openGauss=# select * from pg_get_indexdef(24632, false); pg_get_indexdef ------------------------------------------------------------------------------------------------------------------------------------ -------------------- CREATE INDEX index_sales ON sales USING btree (prod_id) LOCAL(PARTITION idx_p1, PARTITION idx_p2, PARTITION sys_p1_prod_id_idx) TA BLESPACE 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 column_no is not zero.
Example:
openGauss=# 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) openGauss=# select * from pg_get_indexdef(16416, 1, false); pg_get_indexdef ----------------- b (1 row)
Return type: text
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 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: 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
Example:
openGauss=# 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 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: 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, 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:
openGauss=# 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) + TO GROUP group1; (1 row)
Return type: text
pg_get_tabledef(table_name)
Description: Obtains a table definition based on table_name.
Example:
openGauss=# 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) + 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: 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 passed pg_class.reloptions or pg_attribute.attoptions.
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 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: 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. The function is declared as returning regtype, which is an OID alias type (see OID Types). This means that it is the same as an OID for comparison purposes but displays as a type name.
Example:
openGauss=# SELECT pg_typeof(33); pg_typeof ----------- integer (1 row) openGauss=# 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:
openGauss=# 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.
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:
openGauss=# 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:
openGauss=# select * from pg_sequence_parameters(16420); start_value | minimum_value | maximum_value | increment | cycle_option -------------+---------------+---------------------+-----------+-------------- 101 | 1 | 9223372036854775807 | 1 | f (1 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 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: 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 the former is used for retrieving comments on shared objects. Some system catalogs are global to all databases in openGauss, and the comments for objects in them are stored globally as well.
Transaction IDs and Snapshots
Internal transaction IDs (XIDs) are 64 bits. txid_snapshot, the data type used by these functions, stores information about transaction ID visibility at a particular moment. Table 12 describes its components.
Table 12 Snapshot components
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.
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.
txid_current()
Description: Obtains the current transaction ID.
Return type: bigint
gs_txid_oldestxmin()
Description: Obtains the minimum transaction ID (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 transaction IDs 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 transaction ID 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 transaction ID, 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, oid, text
get_remote_prepared_xacts()
Description: Obtains the two-phase residual transaction information of all remote nodes, including the transaction ID, GID of 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
gs_get_next_xid_csn()
Description: Returns the values of next_xid and next_csn on all nodes globally.
The return values are as follows:
Table 13 gs_get_next_xid_csn parameters
slice(hstore, text[])
Description: Extracts the subset of the hstore type.
Return type: hstore
Example:
openGauss=# 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:
openGauss=# 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:
openGauss=# select skeys('a=>1,b=>2'); skeys ------- a b (2 rows)
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
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_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
pg_shared_memory_detail
Description: Returns usage information about all generated shared memory contexts. For details about each column, see GS_SHARED_MEMORY_DETAIL.
Parameter: nan
Return type: contextname text, level smallint, parent text, totalsize bigint, freesize bigint, usedsize bigint
get_gtm_lite_status
Description: Returns the backup XID and CSN on the GTM for fault locating. This system function is not supported in GTM-FREE mode.
gs_stat_get_wlm_plan_operator_info
Description: Obtains operator plan information from the internal hash table.
Parameter: oid
Return type: datname text, queryid int8, plan_node_id int4, startup_time int8, total_time int8, actual_rows int8, max_peak_memory int4, query_dop int4, parent_node_id int4, left_child_id int4, right_child_id int4, operation text, orientation text, strategy text, options text, condition text, projection text
pg_stat_get_partition_tuples_hot_updated
Description: Returns statistics on the number of hot-updated tuples in a partition with a specified partition ID.
Parameter: oid
Return type: bigint
gs_session_memory_detail_tp
Description: Returns the memory usage of the session. For details, see gs_session_memory_detail.
Parameter: nan
Return type: sessid text, sesstype text, contextname text, level smallint, parent text, totalsize bigint, freesize bigint, usedsize bigint
gs_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_stat_get_wlm_realtime_operator_info
Description: Obtains the operator information of the real-time execution plan from the internal hash table.
Parameter: nan
Return type: queryid bigint, pid bigint, plan_node_id integer, plan_node_name text, start_time timestamp with time zone, duration bigint, status text, query_dop integer, estimated_rows bigint, tuple_processed bigint, min_peak_memory integer, max_peak_memory integer, average_peak_memory integer, memory_skew_percent integer, min_spill_size integer, max_spill_size integer, average_spill_size integer, spill_skew_percent integer, min_cpu_time bigint, max_cpu_time bigint, total_cpu_time bigint, cpu_skew_percent integer, warning text
pg_stat_get_wlm_realtime_ec_operator_info
Description: Obtains the operator information of the EC execution plan from the internal hash table.
Parameter: nan
Return type: queryid bigint, plan_node_id integer, plan_node_name text, start_time timestamp with time zone, ec_operator integer, ec_status text, ec_execute_datanode text, ec_dsn text, ec_username text, ec_query text, ec_libodbc_type text, ec_fetch_count bigint
pg_stat_get_wlm_operator_info
Description: Obtains the operator information of the execution plan from the internal hash table.
Parameter: nan
Return type: queryid bigint, pid bigint, plan_node_id integer, plan_node_name text, start_time timestamp with time zone, duration bigint, query_dop integer, estimated_rows bigint, tuple_processed bigint, min_peak_memory integer, max_peak_memory integer, average_peak_memory integer, memory_skew_percent integer, min_spill_size integer, max_spill_size integer, average_spill_size integer, spill_skew_percent integer, min_cpu_time bigint, max_cpu_time bigint, total_cpu_time bigint, cpu_skew_percent integer, warning text
pg_stat_get_wlm_node_resource_info
Description: Obtains the resource information of the current node.
Parameter: nan
Return type: min_mem_util integer, max_mem_util integer, min_cpu_util integer, max_cpu_util integer, min_io_util integer, max_io_util integer, used_mem_rate integer
pg_stat_get_session_wlmstat
Description: Returns the load information of the current session.
Parameter: pid integer
Return type: datid oid, threadid bigint, sessionid bigint, threadpid integer, usesysid oid, appname text, query text, priority bigint, block_time bigint, elapsed_time bigint, total_cpu_time bigint, skew_percent integer, statement_mem integer, active_points integer, dop_value integer, current_cgroup text, current_status text, enqueue_state text, attribute text, is_plana boolean, node_group text, srespool name
pg_stat_get_wlm_ec_operator_info
Description: Obtains the operator information of the EC execution plan from the internal hash table.
Parameter: nan
Return type: queryid bigint, plan_node_id integer, plan_node_name text, start_time timestamp with time zone, duration bigint, tuple_processed bigint, min_peak_memory integer, max_peak_memory integer, average_peak_memory integer, ec_operator integer, ec_status text, ec_execute_datanode text, ec_dsn text, ec_username text, ec_query text, ec_libodbc_type text, ec_fetch_count bigint
pg_stat_get_wlm_instance_info
Description: Returns the load information of the current instance.
Parameter: nan
Return type: instancename text, timestamp, timestamp with time zone, used_cpu integer, free_memory integer, used_memory integer, io_await double precision, io_util double precision, disk_read double precision, disk_write double precision, process_read bigint, process_write bigint, logical_read bigint, logical_write bigint, read_counts bigint, write_counts bigint
pg_stat_get_wlm_instance_info_with_cleanup
Description: Returns the load information of the current instance and saves the information to the system catalog.
Parameter: nan
Return type: instancename text, timestamp, timestamp with time zone, used_cpu integer, free_memory integer, used_memory integer, io_await double precision, io_util double precision, disk_read double precision, disk_write double precision, process_read bigint, process_write bigint, logical_read bigint, logical_write bigint, read_counts bigint, write_counts bigint
pg_stat_get_wlm_realtime_session_info
Description: Returns the load information of the real-time session.
Parameter: nan
Return type: nodename text, threadid bigint, block_time bigint, duration bigint, estimate_total_time bigint, estimate_left_time bigint, schemaname text, query_band text, spill_info text, control_group text, estimate_memory integer, min_peak_memory integer, max_peak_memory integer, average_peak_memory integer, memory_skew_percent integer, min_spill_size integer, max_spill_size integer, average_spill_size integer, spill_skew_percent integer, min_dn_time bigint, max_dn_time bigint, average_dn_time bigint, dntime_skew_percent integer, min_cpu_time bigint, max_cpu_time bigint, total_cpu_time bigint, cpu_skew_percent integer, min_peak_iops integer, max_peak_iops integer, average_peak_iops integer, iops_skew_percent integer, warning text, query text, query_plan text, cpu_top1_node_name text, cpu_top2_node_name text, cpu_top3_node_name text, cpu_top4_node_name text, cpu_top5_node_name text, mem_top1_node_name text, mem_top2_node_name text, mem_top3_node_name text, mem_top4_node_name text, mem_top5_node_name text, cpu_top1_value bigint, cpu_top2_value bigint, cpu_top3_value bigint, cpu_top4_value bigint, cpu_top5_value bigint, mem_top1_value bigint, mem_top2_value bigint, mem_top3_value bigint, mem_top4_value bigint, mem_top5_value bigint, top_mem_dn text, top_cpu_dn 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, curr_io_limits integer
pg_stat_get_wlm_statistics
Description: Returns session load statistics.
Parameter: nan
Return type: statement text, block_time bigint, elapsed_time bigint, total_cpu_time bigint, qualification_time bigint, skew_percent integer, control_group text, status text, action text