Table 8-30 shows several functions that extract session and system information.
Table 8-30. 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 |
session_user | name | session user name |
user | name | equivalent to current_user |
version() | TEXT | EnterpriseDB version information |
The session_user
is the user that initiated a
database connection; it is fixed for the duration of that
connection. The current_user
is the user identifier
that is applicable for permission checking. Normally, it is equal
to the session user, but it 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
, anduser
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 may be altered at run time. The command is:
SET search_path TO schema [, schema, ...]
version()
returns a string describing the
EnterpriseDB server's version.
Table 8-31 lists functions that allow the user to query object access privileges programmatically. See Section 4.6 for more information about privileges.
Table 8-31. Access Privilege Inquiry Functions
Name | Return Type | Description |
---|---|---|
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_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_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 |
has_table_privilege
checks whether a user
can access a table in a particular way. The user can be
specified by name or by ID
(pg_user.usesysid), 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, RULE, REFERENCES, or
TRIGGER. (Case of the string is not significant, however.)
An example is:
SELECT has_table_privilege('myschema.mytable', 'select');
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,
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.
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_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.
To evaluate 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 8-32 lists functions that extract information from the system catalogs.
Table 8-32. System Catalog Information Functions
Name | Return Type | Description |
---|---|---|
pg_get_viewdef (view_name) | TEXT | get CREATE VIEW command for view (deprecated) |
pg_get_viewdef (view_name, pretty_bool) | TEXT | get CREATE VIEW command for view (deprecated) |
pg_get_viewdef (view_oid) | TEXT | get CREATE VIEW command for view |
pg_get_viewdef (view_oid, pretty_bool) | TEXT | get CREATE VIEW command for view |
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_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_triggerdef (trigger_oid) | TEXT | get CREATE [ CONSTRAINT ] TRIGGER command for trigger |
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_userbyid (userid) | name | get user name with given ID |
pg_get_serial_sequence (table_name, column_name) | TEXT | get name of the sequence that a serial or bigserial column uses |
pg_tablespace_databases (tablespace_oid) | setof oid | get set of database OIDs that have objects in the tablespace |
pg_get_viewdef
,
pg_get_ruledef
,
pg_get_indexdef
,
pg_get_triggerdef
, and
pg_get_constraintdef
respectively
reconstruct the creating command for a view, rule, index, trigger, or
constraint. (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
may be useful when examining the contents of system catalogs.
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 EnterpriseDB;
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_userbyid
extracts a user's name given a user ID number.
pg_get_serial_sequence
fetches the name of the sequence associated with a serial or
bigserial column. The name is suitably formatted
for passing to the sequence functions (see Section 8.9).
NULL is returned if the column does not have a sequence attached.
pg_tablespace_databases
allows usage examination of a
tablespace. It will return a set of OIDs of databases that have objects
stored in the tablespace. If this function returns any row, 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 8-33 extract comments previously stored with the COMMENT command. A null value is returned if no comment could be found matching the specified parameters.
Table 8-33. Comment Information Functions
Name | Return Type | Description |
---|---|---|
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) |
col_description (table_oid, column_number) | TEXT | get comment for a table column |
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.
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.