Oracle8i Supplied Packages Reference
Release 8.1.5

A68001-01

Library

Product

Contents

Index

Prev Next

48
DBMS_SQL

Oracle lets you to write stored procedures and anonymous PL/SQL blocks that use dynamic SQL. Dynamic SQL statements are not embedded in your source program; rather, they are stored in character strings that are input to, or built by, the program at runtime. This enables you to create more general-purpose procedures. For example, dynamic SQL lets you create a procedure that operates on a table whose name is not known until runtime.

Additionally, DBMS_SQL enables you to parse any data manipulation language (DML) or data definition language (DDL) statement. Therefore, you can parse DDL statements directly using PL/SQL. For example, you might now choose to enter a DROP TABLE statement from within a stored procedure by using the PARSE procedure supplied with the DBMS_SQL package.


Note:

Oracle8i introduces native dynamic SQL, an alternative to DBMS_SQL. Using native dynamic SQL, you can place dynamic SQL statements directly into PL/SQL blocks.

In most situations, native dynamic SQL can replace DBMS_SQL. Native dynamic SQL is easier to use and performs better than DBMS_SQL.  


See Also:

For more information on native dynamic SQL, see PL/SQL User's Guide and Reference.

For a comparison of DBMS_SQL and native dynamic SQL, see Oracle8i Application Developer's Guide - Fundamentals.  

Using DBMS_SQL

The ability to use dynamic SQL from within stored procedures generally follows the model of the Oracle Call Interface (OCI).

See Also:

Oracle Call Interface Programmer's Guide  

PL/SQL differs somewhat from other common programming languages, such as C. For example, addresses (also called pointers) are not user-visible in PL/SQL. As a result, there are some differences between the Oracle Call Interface and the DBMS_SQL package. These differences include the following:

A sample usage of the DBMS_SQL package is shown below. For users of the Oracle Call Interfaces, this code should seem fairly straightforward.

Example

This example does not actually require the use of dynamic SQL, because the text of the statement is known at compile time. It does, however, illustrate the concepts of this package.

The DEMO procedure deletes all of the employees from the EMP table whose salaries are greater than the salary that you specify when you run DEMO.

CREATE OR REPLACE PROCEDURE demo(salary IN NUMBER) AS
    cursor_name INTEGER;
    rows_processed INTEGER;
BEGIN
    cursor_name := dbms_sql.open_cursor;
    DBMS_SQL.PARSE(cursor_name, 'DELETE FROM emp WHERE sal > :x',
                   dbms_sql.native);
    DBMS_SQL.BIND_VARIABLE(cursor_name, ':x', salary);
    rows_processed := dbms_sql.execute(cursor_name);
    DBMS_SQL.close_cursor(cursor_name);
EXCEPTION
WHEN OTHERS THEN
    DBMS_SQL.CLOSE_CURSOR(cursor_name);
END;

Constants

v6 constant INTEGER     := 0;
native constant INTEGER := 1;
v7 constant INTEGER     := 2;

Types

TYPE varchar2s IS TABLE OF VARCHAR2(256) INDEX BY BINARY_INTEGER;
TYPE desc_rec  IS RECORD (
      col_type            BINARY_INTEGER := 0,
      col_max_len         BINARY_INTEGER := 0,
      col_name            VARCHAR2(32)   := '',
      col_name_len        BINARY_INTEGER := 0,
      col_schema_name     VARCHAR2(32)   := '',
      col_schema_name_len BINARY_INTEGER := 0,
      col_precision       BINARY_INTEGER := 0,
      col_scale           BINARY_INTEGER := 0,
      col_charsetid       BINARY_INTEGER := 0,
      col_charsetform     BINARY_INTEGER := 0,
      col_null_ok         BOOLEAN        := TRUE);
TYPE desc_tab IS TABLE OF desc_rec INDEX BY BINARY_INTEGER;

Bulk SQL Types

type Number_Table   IS TABLE OF NUMBER         INDEX BY BINARY_INTEGER;
type Varchar2_Table IS TABLE OF VARCHAR2(2000) INDEX BY BINARY_INTEGER;
type Date_Table     IS TABLE OF DATE           INDEX BY BINARY_INTEGER; 
type Blob_Table     IS TABLE OF BLOB           INDEX BY BINARY_INTEGER;
type Clob_Table     IS TABLE OF CLOB           INDEX BY BINARY_INTEGER;
type Bfile_Table    IS TABLE OF BFILE          INDEX BY BINARY_INTEGER;

Exceptions

inconsistent_type exception;
  pragma exception_init(inconsistent_type, -6562);

This exception is raised by procedure COLUMN_VALUE or VARIABLE_VALUE when the type of the given OUT parameter (for where to put the requested value) is different from the type of the value.

Execution Flow

OPEN_CURSOR

To process a SQL statement, you must have an open cursor. When you call the OPEN_CURSOR function, you receive a cursor ID number for the data structure representing a valid cursor maintained by Oracle. These cursors are distinct from cursors defined at the precompiler, OCI, or PL/SQL level, and are used only by the DBMS_SQL package.

PARSE

Every SQL statement must be parsed by calling the PARSE procedure. Parsing the statement checks the statement's syntax and associates it with the cursor in your program.

See Also:

Oracle8 Concepts provides an explanation of how SQL statements are parsed.  

You can parse any DML or DDL statement. DDL statements are run on the parse, which performs the implied commit.


Note:

When parsing a DDL statement to drop a package or a procedure, a deadlock can occur if you're still using a procedure in the package. After a call to a procedure, that procedure is considered to be in use until execution has returned to the user side. Any such deadlock timeouts after five minutes.  


Figure 48-1 DBMS_SQL Execution Flow


BIND_VARIABLE or BIND_ARRAY

Many DML statements require that data in your program be input to Oracle. When you define a SQL statement that contains input data to be supplied at runtime, you must use placeholders in the SQL statement to mark where data must be supplied.

For each placeholder in the SQL statement, you must call one of the bind procedures, BIND_VARIABLE or BIND_ARRAY, to supply the value of a variable in your program (or the values of an array) to the placeholder. When the SQL statement is subsequently run, Oracle uses the data that your program has placed in the output and input, or bind, variables.

DBMS_SQL can run a DML statement multiple times -- each time with a different bind variable. The BIND_ARRAY procedure lets you bind a collection of scalars, each value of which is used as an input variable once per EXECUTE. This is similar to the array interface supported by the OCI.

DEFINE_COLUMN, DEFINE_COLUMN_LONG, or DEFINE_ARRAY

The columns of the row being selected in a SELECT statement are identified by their relative positions as they appear in the select list, from left to right. For a query, you must call one of the define procedures (DEFINE_COLUMN, DEFINE_COLUMN_LONG, or DEFINE_ARRAY) to specify the variables that are to receive the SELECT values, much the way an INTO clause does for a static query.

Use the DEFINE_COLUMN_LONG procedure to define LONG columns, in the same way that DEFINE_COLUMN is used to define non-LONG columns. You must call DEFINE_COLUMN_LONG before using the COLUMN_VALUE_LONG procedure to fetch from the LONG column.

Use the DEFINE_ARRAY procedure to define a PL/SQL collection into which you want to fetch rows in a single SELECT statement. DEFINE_ARRAY provides an interface to fetch multiple rows at one fetch. You must call DEFINE_ARRAY before using the COLUMN_VALUE procedure to fetch the rows.

EXECUTE

Call the EXECUTE function to run your SQL statement.

FETCH_ROWS or EXECUTE_AND_FETCH

The FETCH_ROWS function retrieves the rows that satisfy the query. Each successive fetch retrieves another set of rows, until the fetch is unable to retrieve anymore rows. Instead of calling EXECUTE and then FETCH_ROWS, you may find it more efficient to call EXECUTE_AND_FETCH if you are calling EXECUTE for a single execution.

VARIABLE_VALUE, COLUMN_VALUE, or COLUMN_VALUE_LONG

For queries, call COLUMN_VALUE to determine the value of a column retrieved by the FETCH_ROWS call. For anonymous blocks containing calls to PL/SQL procedures or DML statements with returning clause, call VARIABLE_VALUE to retrieve the values assigned to the output variables when statements were run.

To fetch just part of a LONG database column (which can be up to two gigabytes in size), use the COLUMN_VALUE_LONG procedure. You can specify the offset (in bytes) into the column value, and the number of bytes to fetch.

CLOSE_CURSOR

When you no longer need a cursor for a session, close the cursor by calling CLOSE_CURSOR. If you are using an Oracle Open Gateway, then you may need to close cursors at other times as well. Consult your Oracle Open Gateway documentation for additional information.

If you neglect to close a cursor, then the memory used by that cursor remains allocated even though it is no longer needed.

Security

Definer Rights Modules

Definer rights modules run under the privileges of the owner of the module. DBMS_SQL subprograms called from definer rights modules run with respect to the schema in which the module is defined.


Note:

Prior to Oracle 8i, all PL/SQL stored procedures and packages were definer rights modules.  


Invoker Rights Modules

Invoker rights modules run under the privileges of the invoker of the module. Therefore, DBMS_SQL subprograms called from invoker rights modules run under the privileges of the invoker of the module.

When a module has AUTHID set to current_user, the unqualified names are resolved with respect to the invoker's schema.

Example:

income is an invoker rights stored procedure in USER1's schema, and USER2 has been granted EXECUTE privilege on it.

CREATE PROCEDURE income(amount number) 
   AUTHID current_user IS 
   c number;
   n number;
BEGIN 
   c:= dbms_sql.open_cursor;
   dbms_sql.parse(c, 'insert into accts(''income'', :1)', dbms_sql.native);
   dbms_sql.bind_variable(c, '1', amount);
   n := dbms_sql.execute(c);
   dbms_sql.close_cursor(c); 
END; 

If USER1 calls USER1.income, then USER1's privileges are used, and name resolution of unqualified names is done with respect to USER1's schema.

If USER2 calls USER1.income, then USER2's privileges are used, and name resolution of unqualified names (such as accts) is done with respect to USER2's schema.

See Also:

PL/SQL User's Guide and Reference  

Anonymous Blocks

Any DBMS_SQL subprograms called from an anonymous PL/SQL block are run using the privileges of the current user.

Summary of Subprograms

Table 48-1 DBMS_SQL Package Subprograms
Subprogram  Description 
OPEN_CURSOR function
 

Returns cursor ID number of new cursor.  

PARSE procedure
 

Parses given statement.  

BIND_VARIABLE procedure
 

Binds a given value to a given variable.  

BIND_ARRAY procedure
 

Binds a given value to a given collection.  

DEFINE_COLUMN procedure
 

Defines a column to be selected from the given cursor, used only with SELECT statements.  

DEFINE_ARRAY procedure
 

Defines a collection to be selected from the given cursor, used only with SELECT statements.  

DEFINE_COLUMN_LONG procedure
 

Defines a LONG column to be selected from the given cursor, used only with SELECT statements.  

EXECUTE function
 

Executes a given cursor.  

EXECUTE_AND_FETCH function
 

Executes a given cursor and fetch rows.  

FETCH_ROWS function
 

Fetches a row from a given cursor.  

COLUMN_VALUE procedure
 

Returns value of the cursor element for a given position in a cursor.  

COLUMN_VALUE_LONG procedure
 

Returns a selected part of a LONG column, that has been defined using DEFINE_COLUMN_LONG.  

VARIABLE_VALUE procedure
 

Returns value of named variable for given cursor.  

IS_OPEN function
 

Returns TRUE if given cursor is open.  

DESCRIBE_COLUMNS procedure
 

Describes the columns for a cursor opened and parsed through DBMS_SQL.  

CLOSE_CURSOR procedure
 

Closes given cursor and frees memory.  

LAST_ERROR_POSITION function
 

Returns byte offset in the SQL statement text where the error occurred.  

LAST_ROW_COUNT function
 

Returns cumulative count of the number of rows fetched.  

LAST_ROW_ID function
 

Returns ROWID of last row processed.  

LAST_SQL_FUNCTION_CODE 
function
 

Returns SQL function code for statement.  

OPEN_CURSOR function

This procedure opens a new cursor. When you no longer need this cursor, you must close it explicitly by calling CLOSE_CURSOR.

You can use cursors to run the same SQL statement repeatedly or to run a new SQL statement. When a cursor is reused, the contents of the corresponding cursor data area are reset when the new SQL statement is parsed. It is never necessary to close and reopen a cursor before reusing it.

Syntax

DBMS_SQL.OPEN_CURSOR 
   RETURN INTEGER;

Parameters

None.

Pragmas

pragma restrict_references(open_cursor,RNDS,WNDS);

Returns

This function returns the cursor ID number of the new cursor.

PARSE procedure

This procedure parses the given statement in the given cursor. All statements are parsed immediately. In addition, DDL statements are run immediately when parsed.

There are two versions of the PARSE procedure: one uses a VARCHAR2 statement as an argument, and the other uses a VARCHAR2S (table of VARCHAR2) as an argument.


Caution:

Using DBMS_SQL to dynamically run DDL statements can result in the program hanging. For example, a call to a procedure in a package results in the package being locked until the execution returns to the user side. Any operation that results in a conflicting lock, such as dynamically trying to drop the package before the first lock is released, results in a hang.  


The size limit for parsing SQL statements with the syntax above is 32KB.

Syntax

DBMS_SQL.PARSE (
   c                  IN INTEGER,
   statement          IN VARCHAR2,
   language_flag      IN INTEGER);

The PARSE procedure also supports the following syntax for large SQL statements:


Note:

The procedure concatenates elements of a PL/SQL table statement and parses the resulting string. You can use this procedure to parse a statement that is longer than the limit for a single VARCHAR2 variable by splitting up the statement.  


DBMS_SQL.PARSE ( 
   c                  IN INTEGER, 
   statement          IN VARCHAR2S, 
   lb                 IN INTEGER, 
   ub                 IN INTEGER, 
   lfflg              IN BOOLEAN, 
   language_flag      IN INTEGER); 

Parameters

Table 48-2 PARSE Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor in which to parse the statement.  

statement
 

SQL statement to be parsed.

Unlike PL/SQL statements, your SQL statement should not include a final semicolon. For example:

DBMS_SQL.PARSE(cursor1, 'BEGIN proc; END;', 2);
DBMS_SQL.PARSE(cursor1, 'INSERT INTO tab values(1)', 2);
 
lb
 

Lower bound for elements in the statement.  

ub
 

Upper bound for elements in the statement.  

lfflg
 

If TRUE, then insert a linefeed after each element on concatenation.  

language_flag
 

Determines how Oracle handles the SQL statement. The following options are recognized:

  • V6 (or 0) specifies version 6 behavior.

  • NATIVE (or 1) specifies normal behavior for the database to which the program is connected.

  • V7 (or 2) specifies Oracle7 behavior.

 


Note:

Because client-side 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:

DBMS_SQL.PARSE(cur_hdl, stmt_str, dbms_sql.V7); -- uses constant 
dbms_sql.V7

The following code works on the client, because the argument is explicitly provided:

DBMS_SQL.PARSE(cur_hdl, stmt_str, 2); -- compiles on the client
 

VARCHAR2S Datatype for Parsing Large SQL Strings

To parse SQL statements larger than 32 KB, DBMS_SQL makes use of PL/SQL tables to pass a table of strings to the PARSE procedure. These strings are concatenated and then passed on to the Oracle server.

You can declare a local variable as the VARCHAR2S table-item type, and then use the PARSE procedure to parse a large SQL statement as VARCHAR2S.

The definition of the VARCHAR2S datatype is:

TYPE varchar2s IS TABLE OF VARCHAR2(256) INDEX BY BINARY_INTEGER;

Exceptions

If you create a type/procedure/function/package using DBMS_SQL that has 
compilation warnings, an ORA-24344 exception is raised, and the procedure is still 
created.

BIND_VARIABLE procedure

BIND_ARRAY procedure

These two procedures bind a given value or set of values to a given variable in a cursor, based on the name of the variable in the statement. If the variable is an IN or IN/OUT variable or an IN collection, then the given bind value must be valid for the variable or array type. Bind values for OUT variables are ignored.

The bind variables or collections of a SQL statement are identified by their names. When binding a value to a bind variable or bind array, the string identifying it in the statement must contain a leading colon, as shown in the following example:

SELECT emp_name FROM emp WHERE SAL > :X;

For this example, the corresponding bind call would look similar to

BIND_VARIABLE(cursor_name, ':X', 3500); 

or

BIND_VARIABLE (cursor_name, 'X', 3500);

Syntax

DBMS_SQL.BIND_VARIABLE (
   c              IN INTEGER,
   name           IN VARCHAR2,
   value          IN <datatype>); 

Where <datatype> can be any one of the following types:

NUMBER
DATE
VARCHAR2 CHARACTER SET ANY_CS
BLOB
CLOB CHARACTER SET ANY_CS
BFILE

Notice that BIND_VARIABLE is overloaded to accept different datatypes.

See Also:

Oracle8i Application Developer's Guide - Large Objects (LOBs)  

Pragmas

pragma restrict_references(bind_variable,WNDS);

Usage Notes

The following syntax is also supported for BIND_VARIABLE. The square brackets [] indicate an optional parameter for the BIND_VARIABLE function.

DBMS_SQL.BIND_VARIABLE (
   c              IN INTEGER,
   name           IN VARCHAR2,
   value          IN VARCHAR2 CHARACTER SET ANY_CS [,out_value_size IN 
INTEGER]);

To bind CHAR, RAW, and ROWID data, you can use the following variations on the syntax:

DBMS_SQL.BIND_VARIABLE_CHAR (
   c              IN INTEGER,
   name           IN VARCHAR2,
   value          IN CHAR CHARACTER SET ANY_CS [,out_value_size IN INTEGER]);

DBMS_SQL.BIND_VARIABLE_RAW (
   c              IN INTEGER,
   name           IN VARCHAR2,
   value          IN RAW [,out_value_size IN INTEGER]);

DBMS_SQL.BIND_VARIABLE_ROWID (
   c              IN INTEGER,
   name           IN VARCHAR2,
   value          IN ROWID);

Parameters

Table 48-3 BIND_VARIABLE Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor to which you want to bind a value.  

name
 

Name of the variable in the statement.  

value
 

Value that you want to bind to the variable in the cursor.

For IN and IN/OUT variables, the value has the same type as the type of the value being passed in for this parameter.  

out_value_size
 

Maximum expected OUT value size, in bytes, for the VARCHAR2, RAW, CHAR OUT or IN/OUT variable.

If no size is given, then the length of the current value is used. This parameter must be specified if the value parameter is not initialized.  

Bulk Array Binds

Bulk selects, inserts, updates, and deletes can enhance the performance of applications by bundling many calls into one. The DBMS_SQL package lets you work on collections of data using the PL/SQL table type.

Table items are unbounded homogeneous collections. In persistent storage, they are like other relational tables and have no intrinsic ordering. But when a table item is brought into the workspace (either by querying or by navigational access of persistent data), or when it is created as the value of a PL/SQL variable or parameter, its elements are given subscripts that can be used with array-style syntax to get and set the values of elements.

The subscripts of these elements need not be dense, and can be any number including negative numbers. For example, a table item can contain elements at locations -10, 2, and 7 only.

When a table item is moved from transient workspace to persistent storage, the subscripts are not stored; the table item is unordered in persistent storage.

At bind time the table is copied out from the PL/SQL buffers into local DBMS_SQL buffers (the same as for all scalar types) and then the table is manipulated from the local DBMS_SQL buffers. Therefore, if you change the table after the bind call, then that change does not affect the way the execute acts.

Types for Scalar and LOB Collections

You can declare a local variable as one of the following table-item types, which are defined as public types in DBMS_SQL.

type Number_Table   IS TABLE OF NUMBER         INDEX BY BINARY_INTEGER;
type Varchar2_Table IS TABLE OF VARCHAR2(2000) INDEX BY BINARY_INTEGER;
type Date_Table     IS TABLE OF DATE           INDEX BY BINARY_INTEGER;
type Blob_Table     IS TABLE OF BLOB           INDEX BY BINARY_INTEGER;
type Clob_Table     IS TABLE OF CLOB           INDEX BY BINARY_INTEGER;
type Bfile_Table    IS TABLE OF BFILE          INDEX BY BINARY_INTEGER;

Syntax

DBMS_SQL.BIND_ARRAY ( 
   c                   IN INTEGER, 
   name                IN VARCHAR2, 
   <table_variable>    IN <datatype> 
 [,index1              IN INTEGER, 
   index2              IN INTEGER)] ); 

Where the <table_variable> and its corresponding <datatype> can be any one of the following matching pairs:

<num_tab>      Number_Table
<vchr2_tab>    Varchar2_Table
<date_tab>     Date_Table
<blob_tab>     Blob_Table
<clob_tab>     Clob_Table
<bfile_tab>    Bfile_Table

Notice that the BIND_ARRAY procedure is overloaded to accept different datatypes.

Parameters

Table 48-4 BIND_ARRAY Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor to which you want to bind a value.  

name
 

Name of the collection in the statement.  

table_variable
 

Local variable that has been declared as <datatype>.  

index1
 

Index for the table element that marks the lower bound of the range.  

index2
 

Index for the table element that marks the upper bound of the range.  

Usage Notes

For binding a range, the table must contain the elements that specify the range -- tab(index1) and tab(index2) -- but the range does not have to be dense. Index1 must be less than or equal to index2. All elements between tab(index1) and tab(index2) are used in the bind.

If you do not specify indexes in the bind call, and two different binds in a statement specify tables that contain a different number of elements, then the number of elements actually used is the minimum number between all tables. This is also the case if you specify indexes -- the minimum range is selected between the two indexes for all tables.

Not all bind variables in a query have to be array binds. Some can be regular binds and the same value are used for each element of the collections in expression evaluations (and so forth).

See Also:

"Examples 3, 4, and 5: Bulk DML" for examples of how to bind collections.  

Processing Queries

If you are using dynamic SQL to process a query, then you must perform the following steps:

  1. Specify the variables that are to receive the values returned by the SELECT statement by calling DEFINE_COLUMN, DEFINE_COLUMN_LONG, or DEFINE_ARRAY.

  2. Run your SELECT statement by calling EXECUTE.

  3. Call FETCH_ROWS (or EXECUTE_AND_FETCH) to retrieve the rows that satisfied your query.

  4. Call COLUMN_VALUE or COLUMN_VALUE_LONG to determine the value of a column retrieved by the FETCH_ROWS call for your query. If you used anonymous blocks containing calls to PL/SQL procedures, then you must call VARIABLE_VALUE to retrieve the values assigned to the output variables of these procedures.

DEFINE_COLUMN procedure

This procedure defines a column to be selected from the given cursor. This procedure is only used with SELECT cursors.

The column being defined is identified by its relative position in the SELECT list of the statement in the given cursor. The type of the COLUMN value determines the type of the column being defined.

Syntax

DBMS_SQL.DEFINE_COLUMN (
   c              IN INTEGER,
   position       IN INTEGER,
   column         IN <datatype>);

Where <datatype> can be any one of the following types:

NUMBER
DATE
BLOB
CLOB CHARACTER SET ANY_CS
BFILE

Notice that DEFINE_COLUMN is overloaded to accept different datatypes.

See Also:

Oracle8i Application Developer's Guide - Large Objects (LOBs)  

Pragmas

pragma restrict_references(define_column,RNDS,WNDS);

The following syntax is also supported for the DEFINE_COLUMN procedure:

DBMS_SQL.DEFINE_COLUMN (
   c              IN INTEGER,
   position       IN INTEGER,
   column         IN VARCHAR2 CHARACTER SET ANY_CS,
   column_size    IN INTEGER);

To define columns with CHAR, RAW, and ROWID data, you can use the following variations on the procedure syntax:

DBMS_SQL.DEFINE_COLUMN_CHAR (
   c              IN INTEGER,
   position       IN INTEGER,
   column         IN CHAR CHARACTER SET ANY_CS,
   column_size    IN INTEGER);

DBMS_SQL.DEFINE_COLUMN_RAW (
   c              IN INTEGER,
   position       IN INTEGER,
   column         IN RAW,
   column_size    IN INTEGER);

DBMS_SQL.DEFINE_COLUMN_ROWID (
   c              IN INTEGER,
   position       IN INTEGER,
   column         IN ROWID); 

Parameters

Table 48-5 DEFINE_COLUMN Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor for the row being defined to be selected.  

position
 

Relative position of the column in the row being defined.

The first column in a statement has position 1.  

column
 

Value of the column being defined.

The type of this value determines the type for the column being defined.  

column_size
 

Maximum expected size of the column value, in bytes, for columns of type VARCHAR2, CHAR, and RAW.  

DEFINE_ARRAY procedure

This procedure defines the collection for column into which you want to fetch rows (with a FETCH_ROWS call). This procedure lets you do batch fetching of rows from a single SELECT statement. A single fetch call brings over a number of rows into the PL/SQL aggregate object.

When you fetch the rows, they are copied into DBMS_SQL buffers until you run a COLUMN_VALUE call, at which time the rows are copied into the table that was passed as an argument to the COLUMN_VALUE call.

Scalar and LOB Types for Collections

You can declare a local variable as one of the following table-item types, and then fetch any number of rows into it using DBMS_SQL. (These are the same types as you can specify for the BIND_ARRAY procedure.)

type Number_Table   IS TABLE OF NUMBER         INDEX BY BINARY_INTEGER;
type Varchar2_Table IS TABLE OF VARCHAR2(2000) INDEX BY BINARY_INTEGER;
type Date_Table     IS TABLE OF DATE           INDEX BY BINARY_INTEGER;
type Blob_Table     IS TABLE OF BLOB           INDEX BY BINARY_INTEGER;
type Clob_Table     IS TABLE OF CLOB           INDEX BY BINARY_INTEGER;
type Bfile_Table    IS TABLE OF BFILE          INDEX BY BINARY_INTEGER;

Syntax

DBMS_SQL.DEFINE_ARRAY (
   c           IN INTEGER, 
   position    IN INTEGER,
   bf_tab      IN Bfile_Table,
   cnt         IN INTEGER, 
   lower_bound IN INTEGER);

Pragmas

pragma restrict_references(define_array,RNDS,WNDS);

The subsequent FETCH_ROWS call fetch "count" rows. When the COLUMN_VALUE call is made, these rows are placed in positions indx, indx+1, indx+2, and so on. While there are still rows coming, the user keeps issuing FETCH_ROWS/COLUMN_VALUE calls. The rows keep accumulating in the table specified as an argument in the COLUMN_VALUE call.

Parameters

Table 48-6 DEFINE_ARRAY Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor to which you want to bind an array.  

position
 

Relative position of the column in the array being defined.

The first column in a statement has position 1.  

column
 

Type of the value being passed in for this parameter is the type of the column to be defined.  

column_size
 

Maximum expected size of the value in bytes for the VARCHAR2 column.  

The count has to be an integer greater than zero, otherwise an exception is raised. The indx can be positive, negative, or zero. A query on which a DEFINE_ARRAY call was issued cannot contain array binds.

See Also:

"Examples 6 and 7: Defining an Array" for examples of how to define collections.  

DEFINE_COLUMN_LONG procedure

This procedure defines a LONG column for a SELECT cursor. The column being defined is identified by its relative position in the SELECT list of the statement for the given cursor. The type of the COLUMN value determines the type of the column being defined.

Syntax

DBMS_SQL.DEFINE_COLUMN_LONG (
   c              IN INTEGER,
   position       IN INTEGER); 

Parameters

Table 48-7 DEFINE_COLUMN_LONG Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor for the row being defined to be selected.  

position
 

Relative position of the column in the row being defined.

The first column in a statement has position 1.  

EXECUTE function

This function executes a given cursor. This function accepts the ID number of the cursor and returns the number of rows processed. The return value is only valid for INSERT, UPDATE, and DELETE statements; for other types of statements, including DDL, the return value is undefined and should be ignored.

Syntax

DBMS_SQL.EXECUTE (
   c   IN INTEGER)
  RETURN INTEGER;

Parameters

Table 48-8 EXECUTE Function Parameters
Parameter  Description 
c
 

Cursor ID number of the cursor to execute.  

EXECUTE_AND_FETCH function

This function executes the given cursor and fetch rows. This function provides the same functionality as calling EXECUTE and then calling FETCH_ROWS. Calling EXECUTE_AND_FETCH instead, however, may cut down on the number of network round-trips when used against a remote database.

The EXECUTE_AND_FETCH function returns the number of rows actually fetched.

Syntax

DBMS_SQL.EXECUTE_AND_FETCH (
   c              IN INTEGER,
   exact          IN BOOLEAN DEFAULT FALSE)
  RETURN INTEGER;

Pragmas

pragma restrict_references(execute_and_fetch,WNDS);

Parameters

Table 48-9 EXECUTE_AND_FETCH Function Parameters
Parameter  Description 
c
 

ID number of the cursor to execute and fetch.  

exact
 

Set to TRUE to raise an exception if the number of rows actually matching the query differs from one.

Even if an exception is raised, the rows are still fetched and available.  

FETCH_ROWS function

This function fetches a row from a given cursor. You can call FETCH_ROWS repeatedly as long as there are rows remaining to be fetched. These rows are retrieved into a buffer, and must be read by calling COLUMN_VALUE, for each column, after each call to FETCH_ROWS.

The FETCH_ROWS function accepts the ID number of the cursor to fetch, and returns the number of rows actually fetched.

Syntax

DBMS_SQL.FETCH_ROWS (
   c              IN INTEGER)
  RETURN INTEGER;

Parameters

Table 48-10 FETCH_ROWS Function Parameters
Parameter  Description 
c
 

ID number.  

Pragmas

pragma restrict_references(fetch_rows,WNDS);

COLUMN_VALUE procedure

This procedure returns the value of the cursor element for a given position in a given cursor. This procedure is used to access the data fetched by calling FETCH_ROWS.

Syntax

DBMS_SQL.COLUMN_VALUE (
   c                 IN  INTEGER,
   position          IN  INTEGER,
   value             OUT <datatype> 
 [,column_error      OUT NUMBER] 
 [,actual_length     OUT INTEGER]); 

Where <datatype> can be any one of the following types:

NUMBER
DATE
VARCHAR2 CHARACTER SET ANY_CS
BLOB
CLOB CHARACTER SET ANY_CS
BFILE


Note:

The square brackets [ ] indicate optional parameters.  


See Also:

Oracle8i Application Developer's Guide - Large Objects (LOBs)  

Pragmas

pragma restrict_references(column_value,RNDS,WNDS);

The following syntax is also supported for the COLUMN_VALUE procedure:

DBMS_SQL.COLUMN_VALUE( 
   c                 IN  INTEGER, 
   position          IN  INTEGER, 
   <table_variable>  IN  <datatype>); 

Where the <table_variable> and its corresponding <datatype> can be any one of these matching pairs:

<num_tab>      Number_Table
<vchr2_tab>    Varchar2_Table
<date_tab>     Date_Table
<blob_tab>     Blob_Table
<clob_tab>     Clob_Table
<bfile_tab>    Bfile_Table 

For columns containing CHAR, RAW, and ROWID data, you can use the following variations on the syntax:

DBMS_SQL.COLUMN_VALUE_CHAR (
   c               IN  INTEGER,
   position        IN  INTEGER,
   value           OUT CHAR CHARACTER SET ANY_CS
 [,column_error    OUT NUMBER]
 [,actual_length   OUT INTEGER]);
 
DBMS_SQL.COLUMN_VALUE_RAW (
   c               IN  INTEGER,
   position        IN  INTEGER,
   value           OUT RAW
 [,column_error    OUT NUMBER]
 [,actual_length   OUT INTEGER]);

DBMS_SQL.COLUMN_VALUE_ROWID (
   c               IN  INTEGER,
   position        IN  INTEGER,
   value           OUT ROWID
 [,column_error    OUT NUMBER]
 [,actual_length   OUT INTEGER]);

Parameters

Table 48-11 COLUMN_VALUE Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor from which you are fetching the values.  

position
 

Relative position of the column in the cursor.

The first column in a statement has position 1.  

value
 

Returns the value at the specified column and row.

If the row number specified is greater than the total number of rows fetched, then you receive an error message.

Oracle raises exception ORA-06562, inconsistent_type, if the type of this output parameter differs from the actual type of the value, as defined by the call to DEFINE_COLUMN.  

table_variable
 

Local variable that has been declared <datatype>.  

column_error
 

Returns any error code for the specified column value.  

actual_length
 

The actual length, before any truncation, of the value in the specified column.  

Exceptions:

inconsistent_type (ORA-06562) is raised if the type of the given OUT parameter value is different from the actual type of the value. This type was the given type when the column was defined by calling procedure DEFINE_COLUMN.

COLUMN_VALUE_LONG procedure

This procedure gets part of the value of a long column.

Syntax

DBMS_SQL.COLUMN_VALUE_LONG (
   c            IN  INTEGER, 
   position     IN  INTEGER, 
   length       IN  INTEGER, 
   offset       IN  INTEGER,
   value        OUT VARCHAR2,
   value_length OUT INTEGER);

Pragmas

pragma restrict_references(column_value_long,RNDS,WNDS);

Parameters

Table 48-12 COLUMN_VALUE_LONG Procedure Parameters
Parameter  Description 
c
 

Cursor ID number of the cursor from which to get the value.  

position
 

Position of the column of which to get the value.  

length
 

Number of bytes of the long value to fetch.  

offset
 

Offset into the long field for start of fetch.  

value
 

Value of the column as a VARCHAR2.  

value_length
 

Number of bytes actually returned in value.  

VARIABLE_VALUE procedure

This procedure returns the value of the named variable for a given cursor. It is used to return the values of bind variables inside PL/SQL blocks or DML statements with returning clause.

Syntax

DBMS_SQL.VARIABLE_VALUE (
   c               IN  INTEGER,
   name            IN  VARCHAR2,
   value           OUT <datatype>);
 

Where <datatype> can be any one of the following types:

NUMBER
DATE
VARCHAR2 CHARACTER SET ANY_CS 
BLOB 
CLOB CHARACTER SET ANY_CS 
BFILE 

Pragmas

pragma restrict_references(variable_value,RNDS,WNDS);

The following syntax is also supported for the VARIABLE_VALUE procedure:

DBMS_SQL.VARIABLE_VALUE ( 
   c                 IN  INTEGER, 
   name              IN  VARCHAR2,
   <table_variable>  IN  <datatype>); 

Where the <table_variable> and its corresponding <datatype> can be any one of these matching pairs:

<num_tab>      Number_Table
<vchr2_tab>    Varchar2_Table
<date_tab>     Date_Table
<blob_tab>     Blob_Table
<clob_tab>     Clob_Table
<bfile_tab>    Bfile_Table 

For variables containing CHAR, RAW, and ROWID data, you can use the following variations on the syntax:

DBMS_SQL.VARIABLE_VALUE_CHAR (
   c               IN  INTEGER,
   name            IN  VARCHAR2,
   value           OUT CHAR CHARACTER SET ANY_CS);

DBMS_SQL.VARIABLE_VALUE_RAW (
   c               IN  INTEGER,
   name            IN  VARCHAR2,
   value           OUT RAW);

DBMS_SQL.VARIABLE_VALUE_ROWID (
   c               IN  INTEGER,
   name            IN  VARCHAR2,
   value           OUT ROWID);

Parameters

Table 48-13 VARIABLE_VALUE Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor from which to get the values.  

name
 

Name of the variable for which you are retrieving the value.  

value
 

Returns the value of the variable for the specified position.

Oracle raises exception ORA-06562, inconsistent_type, if the type of this output parameter differs from the actual type of the value, as defined by the call to BIND_VARIABLE.  

position
 

Relative position of the column in the cursor.

The first column in a statement has position 1.  

Processing Updates, Inserts and Deletes

If you are using dynamic SQL to process an INSERT, UPDATE, or DELETE, then you must perform the following steps:

  1. You must first run your INSERT, UPDATE, or DELETE statement by calling EXECUTE.

  2. If statements have the returning clause, then you must call VARIABLE_VALUE to retrieve the values assigned to the output variables.

IS_OPEN function

This function checks to see if the given cursor is currently open.

Syntax

DBMS_SQL.IS_OPEN (
   c              IN INTEGER)
  RETURN BOOLEAN;

Pragmas

pragma restrict_references(is_open,RNDS,WNDS);

Parameters

Table 48-14 IS_OPEN Function Parameters
Parameter  Description 
c
 

Cursor ID number of the cursor to check.  

Returns

Table 48-15 IS_OPEN Function Return Values
Return Value  Description 
TRUE
 

Given cursor is currently open.  

FALSE
 

Given cursor is currently not open.  

DESCRIBE_COLUMNS procedure

This procedure describes the columns for a cursor opened and parsed through DBMS_SQL.

The DESC_REC Type

The DBMS_SQL package declares the DESC_REC record type as follows:

type desc_rec is record (  
   col_type            BINARY_INTEGER := 0,
   col_max_len         BINARY_INTEGER := 0,
   col_name            VARCHAR2(32)   := '',
   col_name_len        BINARY_INTEGER := 0,
   col_schema_name     VARCHAR2(32)   := '',
   col_schema_name_len BINARY_INTEGER := 0,
   col_precision       BINARY_INTEGER := 0,
   col_scale           BINARY_INTEGER := 0,
   col_charsetid       BINARY_INTEGER := 0,
   col_charsetform     BINARY_INTEGER := 0,
   col_null_ok         BOOLEAN        := TRUE);

Parameters

Table 48-16 DESC_REC Type Parameters
Parameter  Description 
col_type
 

Type of the column being described.  

col_max_len
 

Maximum length of the column.  

col_name
 

Name of the column.  

col_name_len
 

Length of the column name.  

col_schema_name
 

Name of the schema the column type was defined in, if an object type.  

col_schema_name_len
 

Length of the schema.  

col_precision
 

Column precision, if a number.  

col_scale
 

Column scale, if a number.  

col_charsetid
 

Column character set identifier.  

col_charsetform
 

Column character set form.  

col_null_ok
 

True if column can be null.  

The DESC_TAB Type

The DESC_TAB type is a PL/SQL table of DESC_REC records:

type desc_tab is table of desc_rec index by BINARY_INTEGER;

You can declare a local variable as the PL/SQL table type DESC_TAB, and then call the DESCRIBE_COLUMNS procedure to fill in the table with the description of each column. All columns are described; you cannot describe a single column.

Syntax

DBMS_SQL.DESCRIBE_COLUMNS ( 
   c              IN  INTEGER, 
   col_cnt        OUT INTEGER, 
   desc_t         OUT DESC_TAB);

Parameters

Table 48-17 DBMS_SQL.DESCRIBE_COLUMNS Procedure Parameters
Parameter  Description 
c
 

ID number of the cursor for the columns being described.  

col_cnt
 

Number of columns in the select list of the query.  

desc_t
 

Table of DESC_REC, each DESC_REC describing a column in the query.  

See Also:

"Example 8: Describe Columns" illustrates how to use DESCRIBE_COLUMNS.  

CLOSE_CURSOR procedure

This procedure closes a given cursor.

Syntax

DBMS_SQL.CLOSE_CURSOR (
   c    IN OUT INTEGER);

Pragmas

pragma restrict_references(close_cursor,RNDS,WNDS);

Parameters

Table 48-18 CLOSE_CURSOR Procedure Parameters
Parameter  Mode  Description 
c
 
IN
 

ID number of the cursor that you want to close.  

c
 
OUT
 

Cursor is set to null.

After you call CLOSE_CURSOR, the memory allocated to the cursor is released and you can no longer fetch from that cursor.  

Locating Errors

There are additional functions in the DBMS_SQL package for obtaining information about the last referenced cursor in the session. The values returned by these functions are only meaningful immediately after a SQL statement is run. In addition, some error-locating functions are only meaningful after certain DBMS_SQL calls. For example, you call LAST_ERROR_POSITION immediately after a PARSE.

LAST_ERROR_POSITION function

This function returns the byte offset in the SQL statement text where the error occurred. The first character in the SQL statement is at position 0.

Syntax

DBMS_SQL.LAST_ERROR_POSITION 
   RETURN INTEGER;

Parameters

None.

Pragmas

pragma restrict_references(last_error_position,RNDS,WNDS);

Usage Notes

Call this function after a PARSE call, before any other DBMS_SQL procedures or functions are called.

LAST_ROW_COUNT function

This function returns the cumulative count of the number of rows fetched.

Syntax

DBMS_SQL.LAST_ROW_COUNT 
   RETURN INTEGER;

Parameters

None.

Pragmas

pragma restrict_references(last_row_count,RNDS,WNDS);

Usage Notes

Call this function after a FETCH_ROWS or an EXECUTE_AND_FETCH call. If called after an EXECUTE call, then the value returned is zero.

LAST_ROW_ID function

This function returns the ROWID of the last row processed.

Syntax

DBMS_SQL.LAST_ROW_ID 
   RETURN ROWID;

Parameters

None.

Pragmas

pragma restrict_references(last_row_id,RNDS,WNDS);

Usage Notes

Call this function after a FETCH_ROWS or an EXECUTE_AND_FETCH call.

LAST_SQL_FUNCTION_CODE function

This function returns the SQL function code for the statement. These codes are listed in the Oracle Call Interface Programmer's Guide.

Syntax

DBMS_SQL.LAST_SQL_FUNCTION_CODE 
   RETURN INTEGER;

Parameters

None.

Pragmas

pragma restrict_references(last_sql_function_code,RNDS,WNDS);

Usage Notes

You should call this function immediately after the SQL statement is run; otherwise, the return value is undefined.

Examples

This section provides example procedures that make use of the DBMS_SQL package.

Example 1

The following sample procedure is passed a SQL statement, which it then parses and runs:

CREATE OR REPLACE PROCEDURE exec(STRING IN varchar2) AS
    cursor_name INTEGER;
    ret INTEGER;
BEGIN
   cursor_name := DBMS_SQL.OPEN_CURSOR;
  

DDL statements are run by the parse call, which performs the implied commit.

   DBMS_SQL.PARSE(cursor_name, string, DBMS_SQL.native);
   ret := DBMS_SQL.EXECUTE(cursor_name);
   DBMS_SQL.CLOSE_CURSOR(cursor_name);
END;

Creating such a procedure enables you to perform the following operations:

For example, after creating this procedure, you could make the following call:

exec('create table acct(c1 integer)');

You could even call this procedure remotely, as shown in the following example. This lets you perform remote DDL.

exec@hq.com('CREATE TABLE acct(c1 INTEGER)');
Example 2

The following sample procedure is passed the names of a source and a destination table, and copies the rows from the source table to the destination table. This sample procedure assumes that both the source and destination tables have the following columns:

id        of type NUMBER
name      of type VARCHAR2(30)
birthdate of type DATE

This procedure does not specifically require the use of dynamic SQL; however, it illustrates the concepts of this package.

CREATE OR REPLACE PROCEDURE copy ( 
     source      IN VARCHAR2, 
     destination IN VARCHAR2) IS 
     id_var             NUMBER; 
     name_var           VARCHAR2(30); 
     birthdate_var      DATE; 
     source_cursor      INTEGER; 
     destination_cursor INTEGER; 
     ignore             INTEGER; 
  BEGIN 
 
  -- Prepare a cursor to select from the source table: 
     source_cursor := dbms_sql.open_cursor; 
     DBMS_SQL.PARSE(source_cursor, 
         'SELECT id, name, birthdate FROM ' || source, 
          DBMS_SQL.native); 
     DBMS_SQL.DEFINE_COLUMN(source_cursor, 1, id_var); 
     DBMS_SQL.DEFINE_COLUMN(source_cursor, 2, name_var, 30); 
     DBMS_SQL.DEFINE_COLUMN(source_cursor, 3, birthdate_var); 
     ignore := DBMS_SQL.EXECUTE(source_cursor); 
 
  -- Prepare a cursor to insert into the destination table: 
     destination_cursor := DBMS_SQL.OPEN_CURSOR; 
     DBMS_SQL.PARSE(destination_cursor, 
                  'INSERT INTO ' || destination || 
                  ' VALUES (:id_bind, :name_bind, :birthdate_bind)', 
                   DBMS_SQL.native); 
 
  -- Fetch a row from the source table and insert it into the destination table: 
     LOOP 
       IF DBMS_SQL.FETCH_ROWS(source_cursor)>0 THEN 
         -- get column values of the row 
         DBMS_SQL.COLUMN_VALUE(source_cursor, 1, id_var); 
         DBMS_SQL.COLUMN_VALUE(source_cursor, 2, name_var); 
         DBMS_SQL.COLUMN_VALUE(source_cursor, 3, birthdate_var); 
 
  -- Bind the row into the cursor that inserts into the destination table. You 
  -- could alter this example to require the use of dynamic SQL by inserting an 
  -- if condition before the bind. 
        DBMS_SQL.BIND_VARIABLE(destination_cursor, ':id_bind', id_var); 
        DBMS_SQL.BIND_VARIABLE(destination_cursor, ':name_bind', name_var); 
        DBMS_SQL.BIND_VARIABLE(destination_cursor, ':birthdate_bind', 
birthdate_var); 
        ignore := DBMS_SQL.EXECUTE(destination_cursor); 
      ELSE 
 
  -- No more rows to copy: 
        EXIT; 
      END IF; 
    END LOOP; 
 
  -- Commit and close all cursors: 
     COMMIT; 
     DBMS_SQL.CLOSE_CURSOR(source_cursor); 
     DBMS_SQL.CLOSE_CURSOR(destination_cursor); 
   EXCEPTION 
     WHEN OTHERS THEN 
       IF DBMS_SQL.IS_OPEN(source_cursor) THEN 
         DBMS_SQL.CLOSE_CURSOR(source_cursor); 
       END IF; 
       IF DBMS_SQL.IS_OPEN(destination_cursor) THEN 
         DBMS_SQL.CLOSE_CURSOR(destination_cursor); 
       END IF; 
       RAISE; 
  END; 
/ 
Examples 3, 4, and 5: Bulk DML

This series of examples shows how to use bulk array binds (table items) in the SQL DML statements DELETE, INSERT, and UPDATE.

In a DELETE statement, for example, you could bind in an array in the WHERE clause and have the statement be run for each element in the array:

declare
  stmt varchar2(200);
  dept_no_array dbms_sql.Number_Table;
  c number;
  dummy number;
begin
  dept_no_array(1) := 10; dept_no_array(2) := 20;
  dept_no_array(3) := 30; dept_no_array(4) := 40;
  dept_no_array(5) := 30; dept_no_array(6) := 40;
  stmt := 'delete from emp where deptno = :dept_array';
  c := dbms_sql.open_cursor;
  dbms_sql.parse(c, stmt, dbms_sql.native);
  dbms_sql.bind_array(c, ':dept_array', dept_no_array, 1, 4);
  dummy := dbms_sql.execute(c);
  dbms_sql.close_cursor(c); 

  exception when others then
    if dbms_sql.is_open(c) then
      dbms_sql.close_cursor(c);
    end if;
    raise;
end;
/ 

In the example above, only elements 1 through 4 are used as specified by the bind_array call. Each element of the array potentially deletes a large number of employees from the database.

Here is an example of a bulk INSERT statement:

declare
  stmt varchar2(200);
  empno_array dbms_sql.Number_Table;
  empname_array dbms_sql.Varchar2_Table;
  c number;
  dummy number;
begin
  for i in 0..9 loop
    empno_array(i) := 1000 + i;
    empname_array(I) := get_name(i);
  end loop;
  stmt := 'insert into emp values(:num_array, :name_array)';
  c := dbms_sql.open_cursor;
  dbms_sql.parse(c, stmt, dbms_sql.native);
  dbms_sql.bind_array(c, ':num_array', empno_array);
  dbms_sql.bind_array(c, ':name_array', empname_array);
  dummy := dbms_sql.execute(c);
  dbms_sql.close_cursor(c);

  exception when others then
    if dbms_sql.is_open(c) then
      dbms_sql.close_cursor(c);
    end if;
    raise;
end;
/

When the execute takes place, all 10 of the employees are inserted into the table.

Finally, here is an example of an bulk UPDATE statement.

declare
  stmt varchar2(200);
  emp_no_array dbms_sql.Number_Table;
  emp_addr_array dbms_sql.Varchar2_Table;
  c number;
  dummy number;
begin
  for i in 0..9 loop
    emp_no_array(i) := 1000 + i;
    emp_addr_array(I) := get_new_addr(i);
  end loop;
  stmt := 'update emp set ename = :name_array
    where empno = :num_array';
  c := dbms_sql.open_cursor;
  dbms_sql.parse(c, stmt, dbms_sql.native);
  dbms_sql.bind_array(c, ':num_array', empno_array);
  dbms_sql.bind_array(c, ':name_array', empname_array);
  dummy := dbms_sql.execute(c);
  dbms_sql.close_cursor(c);
  
  exception when others then
    if dbms_sql.is_open(c) then
      dbms_sql.close_cursor(c);
    end if;
    raise;
end;
/

When the EXECUTE call happens, the addresses of all employees are updated at once. The two collections are always stepped in unison. If the WHERE clause returns more than one row, then all those employees get the address the addr_array happens to be pointing to at that time.

Examples 6 and 7: Defining an Array

The following examples show how to use the DEFINE_ARRAY procedure:

declare
  c       number;
  d       number;
  n_tab   dbms_sql.Number_Table;
  indx    number := -10;
begin
  c := dbms_sql.open_cursor;
  dbms_sql.parse(c, 'select n from t order by 1', dbms_sql);

  dbms_sql.define_array(c, 1, n_tab, 10, indx);

  d := dbms_sql.execute(c);
  loop
    d := dbms_sql.fetch_rows(c);

    dbms_sql.column_value(c, 1, n_tab);

    exit when d != 10;
  end loop;

  dbms_sql.close_cursor(c);

  exception when others then
    if dbms_sql.is_open(c) then
      dbms_sql.close_cursor(c);
    end if;
    raise;
end;
/

Each time the example above does a FETCH_ROWS call, it fetches 10 rows that are kept in DBMS_SQL buffers. When the COLUMN_VALUE call is run, those rows move into the PL/SQL table specified (in this case n_tab), at positions -10 to -1, as specified in the DEFINE statements. When the second batch is fetched in the loop, the rows go to positions 0 to 9; and so on.

A current index into each array is maintained automatically. This index is initialized to "indx" at EXECUTE and keeps getting updated every time a COLUMN_VALUE call is made. If you re-execute at any point, then the current index for each DEFINE is re-initialized to "indx".

In this way the entire result of the query is fetched into the table. When FETCH_ROWS cannot fetch 10 rows, it returns the number of rows actually fetched (if no rows could be fetched, then it returns zero) and exits the loop.

Here is another example of using the DEFINE_ARRAY procedure:

Consider a table MULTI_TAB defined as:

create table multi_tab (num number, 
                        dat1 date, 
                        var varchar2(24), 
                        dat2 date) 

To select everything from this table and move it into four PL/SQL tables, you could use the following simple program:

declare
  c       number;
  d       number;
  n_tab  dbms_sql.Number_Table;
  d_tab1 dbms_sql.Date_Table;
  v_tab  dbms_sql.Varchar2_Table;
  d_tab2 dbms_sql.Date_Table;
  indx number := 10;
begin

  c := dbms_sql.open_cursor;
  dbms_sql.parse(c, 'select * from multi_tab order by 1', dbms_sql);

  dbms_sql.define_array(c, 1, n_tab,  5, indx);
  dbms_sql.define_array(c, 2, d_tab1, 5, indx);
  dbms_sql.define_array(c, 3, v_tab,  5, indx);
  dbms_sql.define_array(c, 4, d_tab2, 5, indx);

  d := dbms_sql.execute(c);

  loop
    d := dbms_sql.fetch_rows(c);

    dbms_sql.column_value(c, 1, n_tab);
    dbms_sql.column_value(c, 2, d_tab1);
    dbms_sql.column_value(c, 3, v_tab);
    dbms_sql.column_value(c, 4, d_tab2);
  
    exit when d != 5;
  end loop;

  dbms_sql.close_cursor(c);

/* 

The four tables can be used for anything. One usage might be to use BIND_ARRAY to move the rows to another table by using a query such as 'INSERT into SOME_T values (:a, :b, :c, :d);

*/

exception when others then
    if dbms_sql.is_open(c) then
      dbms_sql.close_cursor(c);
    end if;
    raise;
end;
/
Example 8: Describe Columns

This can be used as a substitute to the SQL*Plus DESCRIBE call by using a SELECT * query on the table that you want to describe.

declare
  c number;
  d number;
  col_cnt integer;
  f boolean;
  rec_tab dbms_sql.desc_tab;
  col_num number;
  procedure print_rec(rec in dbms_sql.desc_rec) is
  begin
    dbms_output.new_line;
    dbms_output.put_line('col_type            =    '
                         || rec.col_type);
    dbms_output.put_line('col_maxlen          =    '
                         || rec.col_max_len);
    dbms_output.put_line('col_name            =    '
                         || rec.col_name);
    dbms_output.put_line('col_name_len        =    '
                         || rec.col_name_len);
    dbms_output.put_line('col_schema_name     =    '
                         || rec.col_schema_name);
    dbms_output.put_line('col_schema_name_len =    '
                         || rec.col_schema_name_len);
    dbms_output.put_line('col_precision       =    '
                         || rec.col_precision);
    dbms_output.put_line('col_scale           =    '
                         || rec.col_scale);
    dbms_output.put('col_null_ok         =    ');
    if (rec.col_null_ok) then
      dbms_output.put_line('true');
    else
      dbms_output.put_line('false');
    end if;
  end;
begin
  c := dbms_sql.open_cursor;

  dbms_sql.parse(c, 'select * from scott.bonus', dbms_sql);
 
  d := dbms_sql.execute(c);
 
  dbms_sql.describe_columns(c, col_cnt, rec_tab);

/*
 * Following loop could simply be for j in 1..col_cnt loop.
 * Here we are simply illustrating some of the PL/SQL table
 * features.
 */
  col_num := rec_tab.first;
  if (col_num is not null) then
    loop
      print_rec(rec_tab(col_num));
      col_num := rec_tab.next(col_num);
      exit when (col_num is null);
    end loop;
  end if;
 
  dbms_sql.close_cursor(c);
end;
/
Example 9: RETURNING clause

The RETURNING clause was added to DML statements in Oracle 8.0.3. With this clause, INSERT, UPDATE, and DELETE statements can return values of expressions. These values are returned in bind variables.

DBMS_SQL.BIND_VARIABLE is used to bind these outbinds if a single row is inserted, updated, or deleted. If multiple rows are inserted, updated, or deleted, then DBMS_SQL.BIND_ARRAY is used. DBMS_SQL.VARIABLE_VALUE must be called to get the values in these bind variables.


Note:

This is similar to DBMS_SQL.VARIABLE_VALUE, which must be called after running a PL/SQL block with an out-bind inside DBMS_SQL.  


i) Single row insert

      create or replace procedure single_Row_insert
           (c1 number, c2 number, r out number) is
      c number;
      n number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'insert into tab values (:bnd1, :bnd2) ' ||
                          'returning c1*c2 into :bnd3', 2);
     dbms_sql.bind_variable(c, 'bnd1', c1);
        dbms_sql.bind_variable(c, 'bnd2', c2);
        dbms_sql.bind_variable(c, 'bnd3', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd3', r); -- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /
 

ii) Single row update

      create or replace procedure single_Row_update
           (c1 number, c2 number, r out number) is
      c number;
      n number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'update tab set c1 = :bnd1, c2 = :bnd2 ' ||
                          'where rownum < 2' || 
                          'returning c1*c2 into :bnd3', 2);
        dbms_sql.bind_variable(c, 'bnd1', c1);
        dbms_sql.bind_variable(c, 'bnd2', c2);
        dbms_sql.bind_variable(c, 'bnd3', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd3', r);-- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /

iii) Single row delete

      create or replace procedure single_Row_Delete
           (c1 number, c2 number, r out number) is
      c number;
      n number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'delete from tab ' ||
                          'where rownum < 2 ' ||
                         'returning c1*c2 into :bnd3', 2);
        dbms_sql.bind_variable(c, 'bnd1', c1);
        dbms_sql.bind_variable(c, 'bnd2', c2);
        dbms_sql.bind_variable(c, 'bnd3', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd3', r);-- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /
 

iv) Multi-row insert

      create or replace procedure multi_Row_insert
           (c1 dbms_sql.number_table, c2 dbms_sql.number_table, 
            r out dbms_sql.number_table) is
      c number;
      n number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'insert into tab values (:bnd1, :bnd2) ' ||
                          'returning c1*c2 into :bnd3', 2);
        dbms_sql.bind_array(c, 'bnd1', c1);
        dbms_sql.bind_array(c, 'bnd2', c2);
        dbms_sql.bind_array(c, 'bnd3', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd3', r);-- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /

v) Multi row Update.

      create or replace procedure multi_Row_update
           (c1 number, c2 number, r out dbms_Sql.number_table) is
      c number;
      n number;
     begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'update tab set c1 = :bnd1 where c2 = :bnd2 ' ||
                          'returning c1*c2 into :bnd3', 2);
        dbms_sql.bind_variable(c, 'bnd1', c1);
        dbms_sql.bind_variable(c, 'bnd2', c2);
        dbms_sql.bind_array(c, 'bnd3', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd3', r);-- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /


Note:

bnd1 and bnd2 can be array as well. The value of the expression for all the rows updated will be in bnd3. There is no way of differentiating which rows got updated of each value of bnd1 and bnd2.  


vi) Multi-row delete

      create or replace procedure multi_row_delete
           (c1 dbms_Sql.number_table,
            r out dbms_sql.number_table) is
      c number;
      n number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'delete from tab where c1 = :bnd1' ||
                          'returning c1*c2 into :bnd2', 2);
        dbms_sql.bind_array(c, 'bnd1', c1);
        dbms_sql.bind_array(c, 'bnd2', r);
        n := dbms_sql.execute(c); 
        dbms_sql.variable_value(c, 'bnd2', r);-- get value of outbind variable
        dbms_Sql.close_Cursor(c);
      end;
      /

vii) Out-bind in bulk PL/SQL

      create or replace foo (n number, square out number) is
      begin square := n * n; end;/
 
      create or replace procedure bulk_plsql 
         (n dbms_sql.number_Table, square out dbms_sql.number_table) is
      c number;
      r number;
      begin
        c := dbms_sql.open_cursor;
        dbms_sql.parse(c, 'begin foo(:bnd1, :bnd2); end;', 2);
        dbms_sql.bind_array(c, 'bnd1', n);
        dbms_Sql.bind_Array(c, 'bnd2', square);
        r := dbms_sql.execute(c);
        dbms_Sql.variable_Value(c, 'bnd2', square);
     end;
     /


Note:

DBMS_SQL.BIND_ARRAY of number_Table internally binds a number. The number of times statement is run depends on the number of elements in an inbind array.  





Prev

Next
Oracle
Copyright © 1999 Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index