PostgreSQL 7.4.30 Documentation | ||||
---|---|---|---|---|
Prev | Fast Backward | Chapter 9. Functions and Operators | Fast Forward | Next |
Table 9-35 shows several functions that extract session and system information.
Table 9-35. 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 | PostgreSQL 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 PostgreSQL
server's version.
Table 9-36 shows the functions available to query and alter run-time configuration parameters.
Table 9-36. Configuration Settings Functions
Name | Return Type | Description |
---|---|---|
current_setting (setting_name) |
text | current value of setting |
set_config(setting_name, new_value, is_local) |
text | set parameter and return new value |
The function current_setting
yields the current value of the setting setting_name. It corresponds to the
SQL command SHOW. An example:
SELECT current_setting('datestyle'); current_setting ----------------- ISO, MDY (1 row)
set_config
sets the parameter
setting_name to new_value. If is_local is true, the
new value will only apply to the current transaction. If you want
the new value to apply for the current session, use false instead. The function corresponds to the SQL
command SET. An example:
SELECT set_config('log_statement_stats', 'off', false); set_config ------------ off (1 row)
Table 9-37 lists functions that allow the user to query object access privileges programmatically. See Section 5.7 for more information about privileges.
Table 9-37. 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_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 currently evaluate to
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 currently 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.
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 9-38 shows functions that determine whether a certain object is visible in the current schema search path. 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:
SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
Table 9-38. Schema Visibility Inquiry Functions
Name | Return Type | Description |
---|---|---|
pg_table_is_visible (table_oid) |
boolean | is table visible in search path |
pg_type_is_visible (type_oid) |
boolean | is type (or domain) 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_conversion_is_visible (conversion_oid) |
boolean | is conversion visible in search path |
pg_table_is_visible
performs the
check for tables (or views, or any other kind of pg_class entry). pg_type_is_visible
, pg_function_is_visible
, pg_operator_is_visible
, pg_opclass_is_visible
, and pg_conversion_is_visible
perform the same sort
of visibility check for types (and domains), functions,
operators, operator classes and conversions, respectively. 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, or regoperator), 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-39
lists functions that extract information from the system
catalogs. 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.) Most of these 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_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.
pg_get_userbyid
extracts a user's
name given a user ID number.
Table 9-39. 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 |
The function shown in Table 9-40 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-40. 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.