SYS_CONTEXT
Syntax
Purpose
SYS_CONTEXT
returns the value of parameter
associated with the context namespace
at the current instant. You can use this function in both SQL and PL/SQL statements. SYS_CONTEXT
must be executed locally.
For namespace
and parameter
, you can specify either a string or an expression that resolves to a string designating a namespace or an attribute. If you specify literal arguments for namespace
and parameter
, and you are using SYS_CONTEXT
explicitly in a SQL statement—rather than in a PL/SQL function that in turn is in mentioned in a SQL statement—then Oracle Database evaluates SYS_CONTEXT
only once per SQL statement execution for each call site that invokes the SYS_CONTEXT
function.
The context namespace
must already have been created, and the associated parameter
and its value must also have been set using the DBMS_SESSION
.set_context
procedure. The namespace
must be a valid identifier. The parameter
name can be any string. It is not case sensitive, but it cannot exceed 30 bytes in length.
The data type of the return value is VARCHAR2
. The default maximum size of the return value is 256 bytes. You can override this default by specifying the optional length
parameter, which must be a NUMBER
or a value that can be implicitly converted to NUMBER
. The valid range of values is 1 to 4000 bytes. If you specify an invalid value, then Oracle Database ignores it and uses the default.
Oracle provides the following built-in namespaces:
-
USERENV
- Describes the current session. The predefined parameters of namespaceUSERENV
are listed in Table 7-11. -
SYS_SESSION_ROLES
- Indicates whether a specified role is currently enabled for the session. Oracle Database evaluates theSYS_SESSION_ROLES
context for the current user, and assumes the defining user's role when it evaluatesSYS_SESSION_ROLES
within a definer's rights procedure or function. An alternative to usingSYS_SESSION_ROLES
to find the login user's enabled roles in a definer’s rights procedure is to use theDBMS_SESSION:SESSION_IS_ROLE_ENABLED
function. Invoker's rights, procedures or functions, and/or code based access control (CBAC) are also alternatives.
See Also:
-
Using Code Based Access Control for Definer's Rights and Invoker's Rights
-
Oracle Database Security Guide for information on using the application context feature in your application development
-
CREATE CONTEXT for information on creating user-defined context namespaces
-
Oracle Database PL/SQL Packages and Types Reference for information on the
DBMS_SESSION
.set_context
procedure -
Appendix C in Oracle Database Globalization Support Guide for the collation derivation rules, which define the collation assigned to the character return value of
SYS_CONTEXT
Examples
The following statement returns the name of the user who logged onto the database:
CONNECT OE
Enter password: password
SELECT SYS_CONTEXT ('USERENV', 'SESSION_USER')
FROM DUAL;
SYS_CONTEXT ('USERENV', 'SESSION_USER')
---------------------------------------
OE
The following example queries the SESSION_ROLES
data dictionary view to show that RESOURCE
is the only role currently enabled for the session. It then uses the SYS_CONTEXT
function to show that the RESOURCE
role is currently enabled for the session and the DBA
role is not.
CONNECT OE
Enter password: password
SELECT role FROM session_roles;
ROLE
--------
RESOURCE
SELECT SYS_CONTEXT('SYS_SESSION_ROLES', 'RESOURCE')
FROM DUAL
SYS_CONTEXT('SYS_SESSION_ROLES','RESOURCE')
--------------------------------------
TRUE
SELECT SYS_CONTEXT('SYS_SESSION_ROLES', 'DBA')
FROM DUAL;
SYS_CONTEXT('SYS_SESSION_ROLES','DBA')
--------------------------------------
FALSE
Note:
For simplicity in demonstrating this feature, these examples do not perform the password management techniques that a deployed system normally uses. In a production environment, follow the Oracle Database password management guidelines, and disable any sample accounts. See Oracle Database Security Guide for password management guidelines and other security recommendations.
The following hypothetical example returns the group number that was set as the value for the attribute group_no
in the PL/SQL package that was associated with the context hr_apps
when hr_apps
was created:
SELECT SYS_CONTEXT ('hr_apps', 'group_no') "User Group" FROM DUAL;
Table 7-11 Predefined Parameters of Namespace USERENV
Parameter | Return Value |
---|---|
|
Identifies the position in the module (application name) and is set through the |
|
Returns the cursor ID of the SQL that triggered the audit. This parameter is not valid in a fine-grained auditing environment. If you specify it in such an environment, then Oracle Database always returns null. |
|
Returns the identity used in authentication. In the list that follows, the type of user is followed by the value returned:
|
|
Data being used to authenticate the login user. For X.503 certificate authenticated sessions, this field returns the context of the certificate in HEX2 format. Note: You can change the return value of the |
|
Returns the method of authentication. In the list that follows, the type of user is followed by the method returned:
For non-administrative connections, you can use |
|
Job ID of the current session if it was established by an Oracle Database background process. Null if the session was not established by a background process. |
|
|
|
If queried while connected to a multitenant container database (CDB), returns the name of the CDB. Otherwise, returns null. |
|
Returns an identifier that is set by the application through the |
|
Returns up to 64 bytes of user session information that can be stored by an application using the |
|
The name of the program used for the database session. |
|
If queried while connected to a CDB, returns the current container ID. Otherwise, returns 0. |
|
If queried while connected to a CDB, returns the current container name. Otherwise, returns the name of the database as specified in the |
|
The bind variables for fine-grained auditing. You can specify this attribute only inside the event handler for the fine-grained auditing feature. |
|
The identifier of the current edition. |
|
The name of the current edition. |
|
The name of the currently active default schema. This value may change during the duration of a session through use of an Note: Oracle recommends against issuing the SQL statement |
|
Identifier of the currently active default schema. |
|
|
|
The length of the current SQL statement that triggers fine-grained audit or row-level security (RLS) policy functions or event handlers. You can specify this attribute only inside the event handler for the fine-grained auditing feature. |
|
The name of the database user whose privileges are currently active. This may change during the duration of a database session as Real Application Security sessions are attached or detached, or to reflect the owner of any active definer's rights object. When no definer's rights object is active, See Also: Oracle Database 2 Day + Security Guide for more information on user |
|
The identifier of the database user whose privileges are currently active. |
|
The database role using the |
|
Domain of the database as specified in the |
|
Name of the database as specified in the |
|
If supplemental logging is enabled, returns a string containing the list of enabled supplemental logging levels. Possible values are: |
|
Name of the database as specified in the |
|
Returns the source of a database link session. Specifically, it returns a string of the form: SOURCE_GLOBAL_NAME=dblink_src_global_name, DBLINK_NAME=dblink_name,
SOURCE_AUDIT_SESSIONID= For a multitenant database, it returns the string above with an additional field SOURCE_GLOBAL_NAME=dblink_src_global_name, SOURCE_DB_NAME=source_database_name, DBLINK_NAME=dblink_name, SOURCE_AUDIT_SESSIONID=dblink_src_audit_sessionid where:
|
|
Displays the draining status for the current session. Returns |
|
The current audit entry number. The audit entryid sequence is shared between fine-grained audit records and regular audit records. You cannot use this attribute in distributed SQL statements. The correct auditing entry identifier can be seen only through an audit handler for standard or fine-grained audit. |
|
Returns the user's enterprise-wide identity:
The value of the attribute differs by proxy method:
|
|
If queried from within a job that was created using the Otherwise: Returns 0. |
|
Returns the number being used in the System Global Area by the globally accessed context. |
|
Returns the global user ID (GUID) from Active Directory for Centrally Managed Users (CMU) logins, or from Oracle Internet Directory for Enterprise User Security (EUS) logins. Returns null for all other logins. |
|
Name of the host machine from which the client has connected. |
|
Returns the way the user's schema was created in the database. Specifically, it reflects the
|
|
The instance identification number of the current instance. |
|
The name of the instance. |
|
IP address of the machine from which the client is connected. If the client and server are on the same machine and the connection uses IPv6 addressing, then |
|
Returns |
|
Returns |
|
Returns |
|
The abbreviated name for the language, a shorter form than the existing ' |
|
The language and territory currently used by your session, along with the database character set, in this form: language_territory.characterset |
|
Returns the configured LDAP server type, one of |
|
The application name (module) set through the |
|
Network protocol being used for communication, as specified in the ' |
|
The current calendar of the current session. |
|
The currency of the current session. |
|
The date format for the session. |
|
The language used for expressing dates. |
|
|
|
The territory of the current session. |
|
The full path name for the Oracle home directory. |
|
Operating system user name of the client process that initiated the database session. |
|
Oracle process ID. |
|
The slash character that is used as the file path delimiter for your platform. |
|
The invoker of row-level security (RLS) policy functions. |
|
Returns the Oracle Internet Directory DN when the proxy user is an enterprise user. |
|
Name of the database user who opened the current session on behalf of |
|
Identifier of the database user who opened the current session on behalf of |
|
Returns |
|
The host name of the machine on which the instance is running. |
|
The name of the service to which a given session is connected. |
|
Specify this parameter under the |
|
The default collation for the session, which is set by the |
|
The identifier of the session edition. |
|
The name of the session edition. |
|
The name of the session user (the user who logged on). This may change during the duration of a database session as Real Application Security sessions are attached or detached. For enterprise users, returns the schema. For other users, returns the database user name. If a Real Application Security session is currently attached to the database session, returns user See Also: Oracle Database 2 Day + Security Guide for more information on user |
|
The identifier of the session user (the user who logged on). |
|
The auditing session identifier. You cannot use this attribute in distributed SQL statements. |
|
The session ID. |
|
The auditing statement identifier. |
|
The operating system identifier for the client of the current session. In distributed SQL statements, this attribute returns the identifier for your local session. In a distributed environment, this is supported only for remote |
|
If queried while connected to a database that uses unified auditing or mixed mode auditing, returns the unified audit session ID. If queried while connected to a database that uses traditional auditing, returns null. |