DBMS_SQL

Related Interfaces

Table 1 lists interfaces supported by the DBMS_SQL package.

Table 1 DBMS_SQL

API

Description

DBMS_SQL.OPEN_CURSOR

Opens a cursor.

DBMS_SQL.CLOSE_CURSOR

Closes an open cursor.

DBMS_SQL.PARSE

Transmits a group of SQL statements to a cursor. Currently, only the SELECT statement is supported.

DBMS_SQL.EXECUTE

Performs a set of dynamically defined operations on the cursor.

DBMS_SQL.FETCHE_ROWS

Reads a row of cursor data.

DBMS_SQL.DEFINE_COLUMN

Dynamically defines a column.

DBMS_SQL.DEFINE_COLUMN_CHAR

Dynamically defines a column of the CHAR type.

DBMS_SQL.DEFINE_COLUMN_INT

Dynamically defines a column of the INT type.

DBMS_SQL.DEFINE_COLUMN_LONG

Dynamically defines a column of the LONG type.

DBMS_SQL.DEFINE_COLUMN_RAW

Dynamically defines a column of the RAW type.

DBMS_SQL.DEFINE_COLUMN_TEXT

Dynamically defines a column of the TEXT type.

DBMS_SQL.DEFINE_COLUMN_UNKNOWN

Dynamically defines a column of an unknown type.

DBMS_SQL.COLUMN_VALUE

Reads a dynamically defined column value.

DBMS_SQL.COLUMN_VALUE_CHAR

Reads a dynamically defined column value of the CHAR type.

DBMS_SQL.COLUMN_VALUE_INT

Reads a dynamically defined column value of the INT type.

DBMS_SQL.COLUMN_VALUE_LONG

Reads a dynamically defined column value of the LONG type.

DBMS_SQL.COLUMN_VALUE_RAW

Reads a dynamically defined column value of the RAW type.

DBMS_SQL.COLUMN_VALUE_TEXT

Reads a dynamically defined column value of the TEXT type.

DBMS_SQL.COLUMN_VALUE_UNKNOWN

Reads a dynamically defined column value of an unknown type.

DBMS_SQL.IS_OPEN

Checks whether a cursor is opened.

  • You are advised to use dbms_sql.define_column and dbms_sql.column_value to define columns.
  • If the size of the result set is greater than the value of work_mem, the result set will be flushed to disk. The value of work_mem must be no greater than 512 MB.

This function returns the status of a cursor: open, parse, execute, or define. The value is TRUE. If the status is unknown, an error is reported. In other cases, the value is FALSE.

The function prototype of DBMS_SQL.IS_OPEN is:
1
2
3
4
DBMS_SQL.IS_OPEN(
cursorid                 IN    INTEGER
)
RETURN BOOLEAN;
Table 20 DBMS_SQL.IS_OPEN interface parameters

Parameter Name

Description

cursorid

ID of the cursor to be queried

Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
-- Perform operations on RAW data in a stored procedure.
create or replace procedure pro_dbms_sql_all_02(in_raw raw,v_in int,v_offset int)
as 
cursorid int;
v_id int;
v_info bytea :=1;
query varchar(2000);
execute_ret int;
define_column_ret_raw bytea :='1';
define_column_ret int;
begin
drop table if exists pro_dbms_sql_all_tb1_02 ;
create table pro_dbms_sql_all_tb1_02(a int ,b blob);
insert into pro_dbms_sql_all_tb1_02 values(1,HEXTORAW('DEADBEEE'));
insert into pro_dbms_sql_all_tb1_02 values(2,in_raw);
query := 'select * from pro_dbms_sql_all_tb1_02 order by 1';
-- Open a cursor.
cursorid := dbms_sql.open_cursor();
-- Compile the cursor.
dbms_sql.parse(cursorid, query, 1);
-- Define a column.
define_column_ret:= dbms_sql.define_column(cursorid,1,v_id);
define_column_ret_raw:= dbms_sql.define_column_raw(cursorid,2,v_info,10);
-- Execute the cursor.
execute_ret := dbms_sql.execute(cursorid);
loop 
exit when (dbms_sql.fetch_rows(cursorid) <= 0);
-- Obtain values.
dbms_sql.column_value(cursorid,1,v_id);
dbms_sql.column_value_raw(cursorid,2,v_info,v_in,v_offset);
-- Output the result.
dbms_output.put_line('id:'|| v_id || ' info:' || v_info);
end loop;
-- Close the cursor.
dbms_sql.close_cursor(cursorid);
end;
/
-- Invoke the stored procedure.
call pro_dbms_sql_all_02(HEXTORAW('DEADBEEF'),0,1);

-- Delete the stored procedure.
DROP PROCEDURE pro_dbms_sql_all_02;