Skip Headers

Oracle9i Supplied PL/SQL Packages and Types Reference
Release 2 (9.2)

Part Number A96612-01
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback

Go to previous page Go to beginning of chapter Go to next page

DBMS_SESSION , 2 of 2


Summary of DBMS_SESSION Subprograms

Table 65-1 DBMS_SESSION Subprograms
Subprogram Description

SET_IDENTIFIER

Sets the identifier.

SET_CONTEXT and

Sets the context.

CLEAR_CONTEXT

Clears the context.

CLEAR_IDENTIFIER

Clears the identifier.

SET_ROLE Procedure

Sets role.

SET_SQL_TRACE Procedure

Turns tracing on or off.

SET_NLS Procedure

Sets national language support (NLS).

CLOSE_DATABASE_LINK Procedure

Closes database link.

RESET_PACKAGE Procedure

Deinstantiates all packages in the session.

MODIFY_PACKAGE_STATE Procedure

Performs actions on the session state of PL/SQL program units that are active in the session.

UNIQUE_SESSION_ID Function

Returns an identifier that is unique for all sessions currently connected to this database.

IS_ROLE_ENABLED Function

Determines if the named role is enabled for the session.

IS_SESSION_ALIVE Function

Determines if the specified session is active.

SET_CLOSE_CACHED_OPEN_CURSORS Procedure

Turns close_cached_open_cursors on or off.

FREE_UNUSED_USER_MEMORY Procedure

Lets you reclaim unused memory after performing operations requiring large amounts of memory.

SET_CONTEXT Procedure

Sets or resets the value of a context attribute.

LIST_CONTEXT Procedure

Returns a list of active namespace and context for the current session.

SWITCH_CURRENT_CONSUMER_GROUP Procedure

Facilitates changing the current resource consumer group of a user's current session.

SET_IDENTIFIER

This procedure sets the client ID in the session.

Syntax

DBMS_SESSION.SET_IDENTIFIER (
   client_id VARCHAR2);

Parameters

Table 65-2 SET_IDENTIFIER Procedure Parameters
Parameter Description

client_id

The application-specific identifier of the current database session.

Usage Notes

Note the following:

SET_CONTEXT

This procedure sets the context.

Syntax

DBMS_SESSION.SET_CONTEXT (
   namespace VARCHAR2,
   attribute VARCHAR2,
   value     VARCHAR2);

Parameters

Table 65-3 SET_CONTEXT Procedure Parameters
Parameter Description

namespace

The namespace of the application context to be set

attribute

The attribute of the application context to be set

value

The value of the application context to be set

Usage Notes

Note the following:

SET_CONTEXT Procedure

This procedure sets the context.

Syntax

DBMS_SESSION.SET_CONTEXT (
   namespace VARCHAR2,
   attribute VARCHAR2,
   value     VARCHAR2,
   username  VARCHAR2,
   client_id VARCHAR2 );

Parameters

Table 65-4 SET_CONTEXT Procedure Parameters
Parameter Description

namespace

The namespace of the application context to be set

attribute

The attribute of the application context to be set

value

The value of the application context to be set

username

The username attribute of the application context

client_id

The client_id attribute of the application context (64-byte maximum)

Usage Notes

Note the following:

CLEAR_CONTEXT

Syntax

DBMS_SESSION.CLEAR_CONTEXT
   namespace         VARCHAR2,
   client_identifier VARCHAR2
   attribute         VARCHAR2);

Parameters

Table 65-5 CLEAR_CONTEXT Procedure Parameters
Parameter Description

namespace

The namespace in which the application context is to be cleared. Required.

For a session-local context, namespace must be specified. If namespace is defined as Session Local Context, then client_identifier is optional since it is only associated with a globally accessed context.

For a globally accessed context, namespace must be specified. NULL is a valid value for client_identifier because a session with no identifier set can see a context that looks like the (namespace,attribute,value,username,null) set using SET_CONTEXT.

client_identifier

Applies to a global context and is optional for other types of contexts; 64-byte maximum.

attribute

The specific attribute in the namespace to be cleared. Optional. the default is NULL. If you specify attribute as NULL, then (namespace,attribute,value) for that namespace are cleared from the session. If attribute is not specified, then all context information that has the namespace and client_identifier arguments is cleared.

Usage Notes

This procedure must be invoked directly or indirectly by the trusted package.

CLEAR_IDENTIFIER

This procedure removes the set_client_id in the session.

Syntax

DBMS_SESSION.CLEAR_IDENTIFIER();

Usage Notes

This procedure is executable by public.

SET_ROLE Procedure

This procedure enables and disables roles. It is equivalent to the SET ROLE SQL statement.

Syntax

DBMS_SESSION.SET_ROLE (
   role_cmd VARCHAR2);

Parameters

Table 65-6 SET_ROLE Procedure Parameters
Parameter Description

role_cmd

This text is appended to "set role" and then run as SQL.

SET_SQL_TRACE Procedure

This procedure turns tracing on or off. It is equivalent to the following SQL statement:

ALTER SESSION SET SQL_TRACE ...

Syntax

DBMS_SESSION.SET_SQL_TRACE (
   sql_trace boolean);

Parameters

Table 65-7 SET_SQL_TRACE Procedure Parameters
Parameter Description

sql_trace

TRUE turns tracing on, FALSE turns tracing off.

SET_NLS Procedure

This procedure sets up your national language support (NLS). It is equivalent to the following SQL statement:

ALTER SESSION SET <nls_parameter> = <value>

Syntax

DBMS_SESSION.SET_NLS (
   param VARCHAR2, 
   value VARCHAR2);

Parameters

Table 65-8 SET_NLS Procedure Parameters
Parameter Description

param

NLS parameter. The parameter name must begin with 'NLS'.

value

Parameter value.

If the parameter is a text literal, then it needs embedded single-quotes. For example, "set_nls('nls_date_format','''DD-MON-YY''')"

CLOSE_DATABASE_LINK Procedure

This procedure closes an open database link. It is equivalent to the following SQL statement:

ALTER SESSION CLOSE DATABASE LINK <name>

Syntax

DBMS_SESSION.CLOSE_DATABASE_LINK (
   dblink VARCHAR2);

Parameters

Table 65-9 CLOSE_DATABASE_LINK Procedure Parameters
Parameter Description

dblink

Name of the database link to close.

RESET_PACKAGE Procedure

This procedure deinstantiates all packages in this session: It frees all package states. See "MODIFY_PACKAGE_STATE Procedure" .

Memory used for caching execution state is associated with all PL/SQL functions, procedures, and packages that have been run in a session.

For packages, this collection of memory holds the current values of package variables and controls the cache of cursors opened by the respective PL/SQL programs. A call to RESET_PACKAGE frees the memory associated with each of the previously run PL/SQL programs from the session, and, consequently, clears the current values of any package globals and closes any cached cursors.

RESET_PACKAGE can also be used to reliably restart a failed program in a session. If a program containing package variables fails, then it is hard to determine which variables need to be reinitialized. RESET_PACKAGE guarantees that all package variables are reset to their initial values.

Syntax

DBMS_SESSION.RESET_PACKAGE; 

Usage Notes

Because the amount of memory consumed by all executed PL/SQL can become large, you might use RESET_PACKAGE to trim down the session memory footprint at certain points in your database application. However, make sure that resetting package variable values will not affect the application. Also, remember that later execution of programs that have lost their cached memory and cursors will perform slower, because they need to re-create the freed memory and cursors.

RESET_PACKAGE does not free the memory, cursors, and package variables immediately when called.


Note:

RESET_PACKAGE only frees the memory, cursors, and package variables after the PL/SQL call that made the invocation finishes running.


For example, PL/SQL procedure P1 calls PL/SQL procedure P2, and P2 calls RESET_PACKAGE. The RESET_PACKAGE effects do not occur until procedure P1 finishes execution (the PL/SQL call ends).

Example

This SQL*Plus script runs a large program with many PL/SQL program units that may or may not use global variables, but it doesn't need them beyond this execution:

EXCECUTE large_plsql_program1; 
 

To free up PL/SQL cached session memory:

EXECUTE DBMS_SESSION.RESET_PACKAGE; 
 

To run another large program:

EXECUTE large_plsql_program2; 

MODIFY_PACKAGE_STATE Procedure

This procedure performs actions on the session state of PL/SQL program units that are active in the session. The procedure uses the DBMS_SESSION constants shown in Table 65-10.

Because the client-side PL/SQL code cannot reference remote package variables or constants, you must explicitly use the values of the constants. For example, the following code does not compile on the client because it uses the constant DBMS_SESSION.REINITIALIZE:

DBMS_SESSION.MODIFY_PACKAGE_STATE(DBMS_SESSION.REINITIALIZE);

Instead, use the following code on the client, because the argument is explicitly provided:

DBMS_SESSION.MODIFY_PACKAGE_STATE(2) -- compiles on the client

DBMS_SESSION.MODIFY_PACKAGE_STATE(DBMS_SESSION.FREE_ALL_RESOURCES)behaves identically to DBMS_SESSION.RESET_PACKAGE. You should use DBMS_SESSION.MODIFY_PACKAGE_STATE(DBMS_SESSION.FREE_ALL_RESOURCES) instead of DBMS_SESSION.RESET_PACKAGE.

Syntax

DBMS_SESSION.MODIFY_PACKAGE_STATE(
   action_flags IN PLS_INTEGER); 

Constants

See "Usage Notes" for differences between the flags and why DBMS_SESSION.REINITIALIZE should exhibit better performance than DBMS_SESSION.FREE_ALL_RESOURCES.

Table 65-10 action_flags Constants for MODIFY_PACKAGE_STATE
Constant Description

FREE_ALL_RESOURCES

PLS_INTEGER := 1

REINITIALIZE

PLS_INTEGER := 2

Parameters

Table 65-11 MODIFY_PACKAGE_STATE Procedure Parameters
Parameter Description

action_flags

Bit flags that determine the action taken on PL/SQL program units:

  • FREE_ALL_RESOURCES (or 1)--frees all memory associated with each of the previously run PL/SQL programs from the session. Clears the current values of any package globals and closes cached cursors. On subsequent use, the PL/SQL program units are reinstantiated and package globals are reinitialized.
  • REINITIALIZE (or 2)--reinitializes packages without actually being freed and re-created from scratch. Instead the package memory is reused.

Usage Notes

Using DBMS_SESSION.MODIFY_PACKAGE_STATE: Example

This example illustrates the use of DBMS_SESSION.MODIFY_PACKAGE_STATE. Consider a package P with some global state (a cursor c and a number cnt). When the package is first initialized, the package variable cnt is 0 and the cursor c is CLOSED. Then, in the session, change the value of cntto 111 and also execute an OPEN operation on the cursor. If you call print_status to display the state of the package, you see that cnt is 111 and that the cursor is OPEN. Next, call DBMS_SESSION.MODIFY_PACKAGE_STATE. If you print the status of the package P again using print_status, you see that cnt is 0 again and the cursor is CLOSED. If the call to DBMS_SESSION.MODIFY_PACKAGE_STATE had not been made, then the second print_status would have printed 111 and OPEN.

create or replace package P is
  cnt    number := 0;
  cursor c is select * from emp;
  procedure print_status;
end P;
/
show errors;

create or replace package body P is
  procedure print_status is
  begin
    dbms_output.put_line('P.cnt = ' || cnt);
    if c%ISOPEN then
      dbms_output.put_line('P.c is OPEN');
    else
      dbms_output.put_line('P.c is CLOSED');
    end if;
  end;
end P;
/
show errors;

SQL> set serveroutput on;
SQL> begin
  2   P.cnt := 111;
  3   open p.c;
  4   P.print_status;
  5  end;
  6  /
P.cnt = 111
P.c is OPEN

PL/SQL procedure successfully completed.

SQL> begin
  2   dbms_session.modify_package_state(dbms_session.reinitialize);
  3  end;
  4  /

PL/SQL procedure successfully completed.

SQL> set serveroutput on;
SQL>
SQL> begin
  2   P.print_status;
  3  end;
  4  /
P.cnt = 0
P.c is CLOSED

PL/SQL procedure successfully completed.

UNIQUE_SESSION_ID Function

This function returns an identifier that is unique for all sessions currently connected to this database. Multiple calls to this function during the same session always return the same result.

Syntax

DBMS_SESSION.UNIQUE_SESSION_ID 
  RETURN VARCHAR2;

Pragmas

pragma restrict_references(unique_session_id,WNDS,RNDS,WNPS);

Returns

Table 65-12 UNIQUE_SESSION_ID Function Returns
Return Description

unique_session_id

Returns up to 24 bytes.

IS_ROLE_ENABLED Function

This function determines if the named role is enabled for this session.

Syntax

DBMS_SESSION.IS_ROLE_ENABLED (
   rolename VARCHAR2) 
  RETURN BOOLEAN;

Parameters

Table 65-13 IS_ROLE_ENABLED Function Parameters
Parameter Description

rolename

Name of the role.

Returns

Table 65-14 IS_ROLE_ENABLED Function Returns
Return Description

is_role_enabled

TRUE or FALSE, depending on whether the role is enabled.

IS_SESSION_ALIVE Function

This function determines if the specified session is active.

Syntax

DBMS_SESSION.IS_SESSION_ALIVE (
   uniqueid VARCHAR2) 
  RETURN BOOLEAN;

Parameters

Table 65-15 IS_SESSION_ALIVE Function Parameters
Parameter Description

uniqueid

Unique ID of the session: This is the same one as returned by UNIQUE_SESSION_ID.

Returns

Table 65-16 IS_SESSION_ALIVE Function Returns
Return Description

is_session_alive

TRUE or FALSE, depending on whether the session is active.

SET_CLOSE_CACHED_OPEN_CURSORS Procedure

This procedure turns close_cached_open_cursors on or off. It is equivalent to the following SQL statement:

ALTER SESSION SET CLOSE_CACHED_OPEN_CURSORS ...

Syntax

DBMS_SESSION.SET_CLOSE_CACHED_OPEN_CURSORS (
   close_cursors BOOLEAN);

Parameters

Table 65-17 SET_CLOSE_CACHED_OPEN_CURSORS Procedure Parameters
Parameter Description

close_cursors

TRUE or FALSE

FREE_UNUSED_USER_MEMORY Procedure

This procedure reclaims unused memory after performing operations requiring large amounts of memory (more than 100K).

Examples of operations that use large amounts of memory include:

You can monitor user memory by tracking the statistics "session uga memory" and "session pga memory" in the v$sesstat or v$statname fixed views. Monitoring these statistics also shows how much memory this procedure has freed.


Note:

This procedure should only be used in cases where memory is at a premium. It should be used infrequently and judiciously.


Syntax

DBMS_SESSION.FREE_UNUSED_USER_MEMORY;

Returns

The behavior of this procedure depends upon the configuration of the server operating on behalf of the client:

Usage Notes

In order to free memory using this procedure, the memory must not be in use.

After an operation allocates memory, only the same type of operation can reuse the allocated memory. For example, after memory is allocated for sort, even if the sort is complete and the memory is no longer in use, only another sort can reuse the sort-allocated memory. For both sort and compilation, after the operation is complete, the memory is no longer in use, and the user can call this procedure to free the unused memory.

An indexed table implicitly allocates memory to store values assigned to the indexed table's elements. Thus, the more elements in an indexed table, the more memory the RDBMS allocates to the indexed table. As long as there are elements within the indexed table, the memory associated with an indexed table is in use.

The scope of indexed tables determines how long their memory is in use. Indexed tables declared globally are indexed tables declared in packages or package bodies. They allocate memory from session memory. For an indexed table declared globally, the memory remains in use for the lifetime of a user's login (lifetime of a user's session), and is freed after the user disconnects from ORACLE.

Indexed tables declared locally are indexed tables declared within functions, procedures, or anonymous blocks. These indexed tables allocate memory from PGA memory. For an indexed table declared locally, the memory remains in use for as long as the user is still running the procedure, function, or anonymous block in which the indexed table is declared.After the procedure, function, or anonymous block is finished running, the memory is then available for other locally declared indexed tables to use (in other words, the memory is no longer in use).

Assigning an uninitialized, "empty" indexed table to an existing index table is a method to explicitly re-initialize the indexed table and the memory associated with the indexed table. After this operation, the memory associated with the indexed table is no longer in use, making it available to be freed by calling this procedure. This method is particularly useful on indexed tables declared globally which can grow during the lifetime of a user's session, as long as the user no longer needs the contents of the indexed table.

The memory rules associated with an indexed table's scope still apply; this method and this procedure, however, allow users to intervene and to explicitly free the memory associated with an indexed table.

Example

The following PL/SQL illustrates the method and the use of procedure FREE_UNUSED_USER_MEMORY.

CREATE PACKAGE foobar
   type number_idx_tbl is table of number indexed by binary_integer;

   store1_table  number_idx_tbl;     --  PL/SQL indexed table
   store2_table  number_idx_tbl;     --  PL/SQL indexed table
   store3_table  number_idx_tbl;     --  PL/SQL indexed table
   ...
END;            --  end of foobar

DECLARE
   ...
   empty_table   number_idx_tbl;     --  uninitialized ("empty") version
BEGIN
   FOR i in 1..1000000 loop
     store1_table(i) := i;           --  load data
   END LOOP;
   ...
   store1_table := empty_table;      --  "truncate" the indexed table
   ... 
   -
   dbms_session.free_unused_user_memory;  -- give memory back to system

   store1_table(1) := 100;           --  index tables still declared;
   store2_table(2) := 200;           --  but truncated.
   ...
END;

SET_CONTEXT Procedure

This procedure sets or resets the value of a context attribute.

Syntax

DBMS_SESSION.SET_CONTEXT (
   namespace VARCHAR2, 
   attribute VARCHAR2, 
   value     VARCHAR2,
   username  VARCHAR2,
   client_id VARCHAR2);

Parameters

Table 65-18 SET_CONTEXT Procedure Parameters
Parameter Description

namespace

Name of the namespace to use for the application context (limited to 30 bytes).

attribute

Name of the attribute to be set (limited to 30 bytes).

value

Value to be set (limited to 4 kilobytes).

username

The username attribute of the application context

client_id

The application-specific identifier of the current database session.

Usage Notes

The caller of this function must be in the calling stack of a procedure which has been associated to the context namespace through a CREATE CONTEXT statement. The checking of the calling stack does not cross DBMS boundary.

There is no limit on the number of attributes that can be set in a namespace. An attribute value remains for user session, or until it is reset by the user.

LIST_CONTEXT Procedure

This procedure returns a list of active namespaces and contexts for the current session.

Syntax

TYPE AppCtxRecTyp IS RECORD ( 
   namespace VARCHAR2(30), 
   attribute VARCHAR2(30),
   value     VARCHAR2(256)); 

TYPE AppCtxTabTyp IS TABLE OF AppCtxRecTyp INDEX BY BINARY_INTEGER; 

DBMS_SESSION.LIST_CONTEXT ( 
   list OUT AppCtxTabTyp, 
   size OUT NUMBER);

Parameters

Table 65-19 LIST_CONTEXT Procedure Parameters
Parameter Description

list

Buffer to store a list of application context set in the current session.

Returns

Table 65-20 LIST_CONTEXT Procedure Returns
Return Description

list

A list of (namespace, attribute, values) set in current session

size

Returns the number of entries in the buffer returned

Usage Notes

The context information in the list appears as a series of <namespace> <attribute> <value>. Because list is a table type variable, its size is dynamically adjusted to the size of returned list.

SWITCH_CURRENT_CONSUMER_GROUP Procedure

This procedure changes the current resource consumer group of a user's current session.

This lets you switch to a consumer group if you have the switch privilege for that particular group. If the caller is another procedure, then this enables the user to switch to a consumer group for which the owner of that procedure has switch privilege.

Syntax

DBMS_SESSION.switch_current_consumer_group (
   new_consumer_group     IN  VARCHAR2, 
   old_consumer_group     OUT VARCHAR2, 
   initial_group_on_error IN  BOOLEAN); 

Parameters

Table 65-21 SWITCH_CURRENT_CONSUMER_GROUP Procedure Parameters
Parameter Description

new_consumer_group

Name of consumer group to which you want to switch.

old_consumer_group

Name of the consumer group from which you just switched out.

initial_group_on_error

If TRUE, then sets the current consumer group of the caller to his/her initial consumer group in the event of an error.

Returns

This procedure outputs the old consumer group of the user in the parameter old_consumer_group.


Note:

You can switch back to the old consumer group later using the value returned in old_consumer_group.


Exceptions

Table 65-22 SWITCH_CURRENT_CONSUMER_GROUP Procedure Exceptions
Exception Description

29368

Non-existent consumer group.

1031

Insufficient privileges.

29396

Cannot switch to OTHER_GROUPS consumer group.

Usage Notes

The owner of a procedure must have privileges on the group from which a user was switched (old_consumer_group) in order to switch them back. There is one exception: The procedure can always switch the user back to his/her initial consumer group (skipping the privilege check).

By setting initial_group_on_error to TRUE, SWITCH_CURRENT_CONSUMER_GROUP puts the current session into the default group, if it can't put it into the group designated by new_consumer_group. The error associated with the attempt to move a session into new_consumer_group is raised, even though the current consumer group has been changed to the initial consumer group.

Example

CREATE OR REPLACE PROCEDURE high_priority_task is 
   old_group varchar2(30); 
   prev_group varchar2(30); 
   curr_user varchar2(30);  
BEGIN 
  -- switch invoker to privileged consumer group. If we fail to do so, an 
  -- error will be thrown, but the consumer group will not change 
  -- because 'initial_group_on_error' is set to FALSE 
 
  dbms_session.switch_current_consumer_group('tkrogrp1', old_group, FALSE); 
  -- set up exception handler (in the event of an error, we do not want to 
  -- return to caller while leaving the session still in the privileged 
  -- group) 
 
  BEGIN 
    -- perform some operations while under privileged group 
 
  EXCEPTION 
    WHEN OTHERS THEN 
     -- It is possible that the procedure owner does not have privileges 
     -- on old_group. 'initial_group_on_error' is set to TRUE to make sure 
     -- that the user is moved out of the privileged group in such a 
     -- situation 
 
     dbms_session.switch_current_consumer_group(old_group,prev_group,TRUE); 
     RAISE; 
    END; 
 
  -- we've succeeded. Now switch to old_group, or if cannot do so, switch 
  -- to caller's initial consumer group 
 
  dbms_session.switch_current_consumer_group(old_group,prev_group,TRUE); 
END high_priority_task; 
/  

Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 2000, 2002 Oracle Corporation.

All Rights Reserved.
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback