Supported Versions: Current (17) / 16 / 15 / 14 / 13
Development Versions: devel
Unsupported versions: 12 / 11 / 10 / 9.6 / 9.5 / 9.4 / 9.3 / 9.2 / 9.1 / 9.0 / 8.4 / 8.3 / 8.2 / 8.1 / 8.0
This documentation is for an unsupported version of PostgreSQL.
You may want to view the same page for the current version, or one of the other supported versions listed above instead.

9.22. System Information Functions

Table 9-44 shows several functions that extract session and system information.

In addition to the functions listed in this section, there are a number of functions related to the statistics system that also provide system information. See Section 26.2.2 for more information.

Table 9-44. Session Information Functions

Name Return Type Description
current_database() name name of current database
current_schema() name name of current schema
current_schemas(boolean) name[] names of schemas in search path optionally including implicit schemas
current_user name user name of current execution context
inet_client_addr() inet address of the remote connection
inet_client_port() int port of the remote connection
inet_server_addr() inet address of the local connection
inet_server_port() int port of the local connection
pg_my_temp_schema() oid OID of session's temporary schema, or 0 if none
pg_is_other_temp_schema(oid) boolean is schema another session's temporary schema?
pg_postmaster_start_time() timestamp with time zone server start time
session_user name session user name
user name equivalent to current_user
version() text PostgreSQL version information

The session_user is normally the user who initiated the current database connection; but superusers can change this setting with SET SESSION AUTHORIZATION. The 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. In Unix parlance, the session user is the "real user" and the current user is the "effective user".

Note: current_user, session_user, and user have special syntactic status in SQL: they must be called without trailing parentheses.

current_schema returns the name of the schema that is at the front of the search path (or a null value if the search path is empty). 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) returns an array of the names of all schemas presently in the search path. The Boolean option determines whether or not implicitly included system schemas such as pg_catalog are included in the search path returned.

Note: The search path can be altered at run time. The command is:

SET search_path TO schema [, schema, ...]

inet_client_addr returns the IP address of the current client, and inet_client_port returns the port number. inet_server_addr returns the IP address on which the server accepted the current connection, and inet_server_port returns the port number. All these functions return NULL if the current connection is via a Unix-domain socket.

pg_my_temp_schema returns the OID of the current session's temporary schema, or 0 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 any other session's temporary schema. (This can be useful, for example, to exclude other sessions' temporary tables from a catalog display.)

pg_postmaster_start_time returns the timestamp with time zone when the server started.

version returns a string describing the PostgreSQL server's version.

Table 9-45 lists functions that allow the user to query object access privileges programmatically. See Section 5.6 for more information about privileges.

Table 9-45. Access Privilege Inquiry Functions

Name Return Type Description
has_database_privilege(user, database, privilege) boolean does user have privilege for database
has_database_privilege(database, privilege) boolean does current user have privilege for database
has_function_privilege(user, function, privilege) boolean does user have privilege for function
has_function_privilege(function, privilege) boolean does current user have privilege for function
has_language_privilege(user, language, privilege) boolean does user have privilege for language
has_language_privilege(language, privilege) boolean does current user have privilege for language
has_schema_privilege(user, schema, privilege) boolean does user have privilege for schema
has_schema_privilege(schema, privilege) boolean does current user have privilege for schema
has_table_privilege(user, table, privilege) boolean does user have privilege for table
has_table_privilege(table, privilege) boolean does current user have privilege for table
has_tablespace_privilege(user, tablespace, privilege) boolean does user have privilege for tablespace
has_tablespace_privilege(tablespace, privilege) boolean does current user have privilege for tablespace
pg_has_role(user, role, privilege) boolean does user have privilege for role
pg_has_role(role, privilege) boolean does current user have privilege for role

has_database_privilege checks whether a user can access a database in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access privilege type must evaluate to CREATE, CONNECT, TEMPORARY, or TEMP (which is equivalent to TEMPORARY).

has_function_privilege checks whether a user can access a function in a particular way. The possibilities for its arguments are analogous to has_table_privilege. When specifying a function by a text string rather than by OID, the allowed input is the same as for the regprocedure data type (see Section 8.16). The desired access privilege type must evaluate to EXECUTE. An example is:

SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');

has_language_privilege checks whether a user can access a procedural language in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access privilege type must evaluate to USAGE.

has_schema_privilege checks whether a user can access a schema in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access privilege type must evaluate to CREATE or USAGE.

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 if the argument is omitted current_user is assumed. The table can be specified by name or by OID. (Thus, there are actually six variants of has_table_privilege, which can be distinguished by the number and types of their arguments.) When specifying by name, the name can be schema-qualified if necessary. The desired access privilege type is specified by a text string, which must evaluate to one of the values SELECT, INSERT, UPDATE, DELETE, REFERENCES, or TRIGGER. (Case of the string is not significant, however.) An example is:

SELECT has_table_privilege('myschema.mytable', 'select');

has_tablespace_privilege checks whether a user can access a tablespace in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access privilege type must evaluate to CREATE.

pg_has_role checks whether a user can access a role in a particular way. The possibilities for its arguments are analogous to has_table_privilege. The desired access privilege type must evaluate to MEMBER or USAGE. MEMBER denotes direct or indirect membership in the role (that is, the right to do SET ROLE), while USAGE denotes whether the privileges of the role are immediately available without doing SET ROLE.

To test whether a user holds a grant option on the privilege, append WITH GRANT OPTION to the privilege key word; for example 'UPDATE WITH GRANT OPTION'.

Table 9-46 shows functions that determine whether a certain object is visible in the current schema search path. 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. To list the names of all visible tables:

SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);

Table 9-46. Schema Visibility Inquiry Functions

Name Return Type Description
pg_conversion_is_visible(conversion_oid) boolean is conversion visible in search path
pg_function_is_visible(function_oid) boolean is function visible in search path
pg_operator_is_visible(operator_oid) boolean is operator visible in search path
pg_opclass_is_visible(opclass_oid) boolean is operator class visible in search path
pg_table_is_visible(table_oid) boolean is table visible in search path
pg_ts_config_is_visible(config_oid) boolean is text search configuration visible in search path
pg_ts_dict_is_visible(dict_oid) boolean is text search dictionary visible in search path
pg_ts_parser_is_visible(parser_oid) boolean is text search parser visible in search path
pg_ts_template_is_visible(template_oid) boolean is text search template visible in search path
pg_type_is_visible(type_oid) boolean is type (or domain) visible in search path

Each function performs the visibility check for one type of database object. Note that pg_table_is_visible can also be used with views, indexes and sequences; pg_type_is_visible can also be used with domains. For functions and operators, an object in the search path is visible if there is no object of the same name and argument data type(s) earlier in the path. For operator classes, both name and associated index access method are considered.

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

SELECT pg_type_is_visible('myschema.widget'::regtype);

Note that it would not make much sense to test an unqualified name in this way — if the name can be recognized at all, it must be visible.

Table 9-47 lists functions that extract information from the system catalogs.

Table 9-47. System Catalog Information Functions

Name Return Type Description
format_type(type_oid, typemod) text get SQL name of a data type
pg_get_constraintdef(constraint_oid) text get definition of a constraint
pg_get_constraintdef(constraint_oid, pretty_bool) text get definition of a constraint
pg_get_expr(expr_text, relation_oid) text decompile internal form of an expression, assuming that any Vars in it refer to the relation indicated by the second parameter
pg_get_expr(expr_text, relation_oid, pretty_bool) text decompile internal form of an expression, assuming that any Vars in it refer to the relation indicated by the second parameter
pg_get_indexdef(index_oid) text get CREATE INDEX command for index
pg_get_indexdef(index_oid, column_no, pretty_bool) text get CREATE INDEX command for index, or definition of just one index column when column_no is not zero
pg_get_ruledef(rule_oid) text get CREATE RULE command for rule
pg_get_ruledef(rule_oid, pretty_bool) text get CREATE RULE command for rule
pg_get_serial_sequence(table_name, column_name) text get name of the sequence that a serial or bigserial column uses
pg_get_triggerdef(trigger_oid) text get CREATE [ CONSTRAINT ] TRIGGER command for trigger
pg_get_userbyid(roleid) name get role name with given ID
pg_get_viewdef(view_name) text get underlying SELECT command for view (deprecated)
pg_get_viewdef(view_name, pretty_bool) text get underlying SELECT command for view (deprecated)
pg_get_viewdef(view_oid) text get underlying SELECT command for view
pg_get_viewdef(view_oid, pretty_bool) text get underlying SELECT command for view
pg_tablespace_databases(tablespace_oid) setof oid get the set of database OIDs that have objects in the tablespace

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.

pg_get_constraintdef, pg_get_indexdef, pg_get_ruledef, and pg_get_triggerdef, respectively reconstruct the creating command for a constraint, index, rule, or trigger. (Note that this is a decompiled reconstruction, not the original text of the command.) 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. pg_get_viewdef reconstructs the SELECT query that defines a view. Most of these functions come in two variants, one of which can optionally "pretty-print" the result. The pretty-printed format is more readable, but the default format 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_serial_sequence returns the name of the sequence associated with a column, or NULL if no sequence is associated with the column. The first input parameter is a table name with optional schema, and the second parameter is a column name. Because the first parameter is potentially a schema and table, it is not treated as a double-quoted identifier, meaning it is lowercased by default, while the second parameter, being just a column name, is treated as double-quoted and has its case preserved. The function returns a value suitably formatted for passing to the sequence functions (see Section 9.15). This association can be modified or removed with ALTER SEQUENCE OWNED BY. (The function probably should have been called pg_get_owned_sequence; its name reflects the fact that it's typically used with serial or bigserial columns.)

pg_get_userbyid extracts a role's name given its OID.

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.

The functions shown in Table 9-48 extract comments previously stored with the COMMENT command. A null value is returned if no comment could be found matching the specified parameters.

Table 9-48. Comment Information Functions

Name Return Type Description
col_description(table_oid, column_number) text get comment for a table column
obj_description(object_oid, catalog_name) text get comment for a database object
obj_description(object_oid) text get comment for a database object (deprecated)
shobj_description(object_oid, catalog_name) text get comment for a shared database object

col_description returns the comment for a table column, which is specified by the OID of its table and its column number. obj_description cannot be used for table columns since columns do not have OIDs of their own.

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 a table with OID 123456. The one-parameter form of obj_description requires only the object OID. It is now deprecated since there is no guarantee that OIDs are unique across different system catalogs; therefore, the wrong comment could be returned.

shobj_description is used just like obj_description only that it is used for retrieving comments on shared objects. Some system catalogs are global to all databases within each cluster and their descriptions are stored globally as well.

The functions shown in Table 9-49 export server internal transaction information to user level. The main use of these functions is to determine which transactions were committed between two snapshots.

Table 9-49. Transaction IDs and snapshots

Name Return Type Description
txid_current() bigint get current transaction ID
txid_current_snapshot() txid_snapshot get current snapshot
txid_snapshot_xmin(txid_snapshot) bigint get xmin of snapshot
txid_snapshot_xmax(txid_snapshot) bigint get xmax of snapshot
txid_snapshot_xip(txid_snapshot) setof bigint get in-progress transaction IDs in snapshot
txid_visible_in_snapshot(bigint, txid_snapshot) boolean is transaction ID visible in snapshot?

The internal transaction ID type (xid) is 32 bits wide and so it wraps around every 4 billion transactions. However, these functions export a 64-bit format that is extended with an "epoch" counter so that it will not wrap around for the life of an installation. The data type used by these functions, txid_snapshot, stores information about transaction ID visibility at a particular moment in time. Its components are described in Table 9-50.

Table 9-50. Snapshot components

Name Description
xmin Earliest transaction ID (txid) that is still active. All earlier transactions will either be committed and visible, or rolled back and dead.
xmax First as-yet-unassigned txid. All txids later than this one are not yet started as of the time of the snapshot, and thus invisible.
xip_list Active txids at the time of the snapshot. All of them are between xmin and xmax. A txid that is xmin <= txid < xmax and not in this list was already completed at the time of the snapshot, and thus either visible or dead according to its commit status.

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.