iSQL*Plus User's Guide and Reference
Release 9.0.1

Part Number A88826-01
GRORACLE GRORACLE
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

Command Reference, 36 of 38


VARIABLE

VAR[IABLE] [variable [NUMBER|CHAR|CHAR (n [CHAR|BYTE])|NCHAR|NCHAR (n)
|VARCHAR2 (n [CHAR|BYTE])|NVARCHAR2 (n)|CLOB|NCLOB|REFCURSOR]]

Declares a bind variable that can then be referenced in PL/SQL. For more information about PL/SQL, see your PL/SQL User's Guide and Reference.

VARIABLE without arguments displays a list of all the variables declared in the session. VARIABLE followed only by a variable name lists that variable.

Terms | Usage | Examples | Top

Refer to the following list for a description of each term or clause:

variable

NUMBER

CHAR

CHAR (n[CHAR|BYTE])

NCHAR

NCHAR (n)

VARCHAR2 (n[CHAR|BYTE])

NVARCHAR2 (n)

CLOB

NCLOB

REFCURSOR

Usage | Terms | Examples | Top

Bind variables may be used as parameters to stored procedures, or may be directly referenced in anonymous PL/SQL blocks.

To display the value of a bind variable created with VARIABLE, use the PRINT command. For more information, see the PRINT command in this chapter.

To automatically display the value of a bind variable created with VARIABLE, use the SET AUTOPRINT command. For more information, see the SET AUTOPRINT command in this chapter.

Bind variables cannot be used in the COPY command or SQL statements, except in PL/SQL blocks. Instead, use substitution variables.

When you execute a VARIABLE ... CLOB or NCLOB command, SQL*Plus associates a LOB locator with the bind variable. The LOB locator is automatically populated when you execute a SELECT clob_column INTO :cv statement in a PL/SQL block. SQL*Plus closes the LOB locator after completing a PRINT statement for that bind variable, or when you exit SQL*Plus.

SQL*Plus SET commands such as SET LONG and SET LONGCHUNKSIZE and SET LOBOFFSET may be used to control the size of the buffer while PRINTing CLOB or NCLOB bind variables.

SQL*Plus REFCURSOR bind variables may be used to reference PL/SQL 2.3 or higher Cursor Variables, allowing PL/SQL output to be formatted by SQL*Plus. For more information on PL/SQL Cursor Variables, see your PL/SQL User's Guide and Reference.

When you execute a VARIABLE ... REFCURSOR command, SQL*Plus creates a cursor bind variable. The cursor is automatically opened by an OPEN ... FOR SELECT statement referencing the bind variable in a PL/SQL block. SQL*Plus closes the cursor after completing a PRINT statement for that bind variable, or on exit.

SQL*Plus formatting commands such as BREAK, COLUMN, COMPUTE and SET may be used to format the output from PRINTing a REFCURSOR.

A REFCURSOR bind variable may not be PRINTed more than once without re-executing the PL/SQL OPEN ... FOR statement.

Examples | Terms | Usage | Top

The following example illustrates creating a bind variable and then setting it to the value returned by a function:

Keyboard icon
VARIABLE id NUMBER
BEGIN
  :id := EMP_MANAGEMENT.HIRE
  ('BLAKE','MANAGER','KING',2990,'SALES');
END;
/

The value returned by the stored procedure is being placed in the bind variable, :id. It can be displayed with the PRINT command or used in subsequent PL/SQL subprograms.

The following example illustrates automatically displaying a bind variable:

Keyboard icon
SET AUTOPRINT ON
VARIABLE a REFCURSOR
BEGIN
  OPEN :a FOR SELECT LAST_NAME, CITY, DEPARTMENT_ID
  FROM EMP_DETAILS_VIEW
  WHERE SALARY > 12000
  ORDER BY DEPARTMENT_ID;
END;
/

Screen icon
PL/SQL procedure successfully completed.

LAST_NAME                 CITY                           DEPARTMENT_ID
------------------------- ------------------------------ -------------
Hartstein                 Toronto                                   20
Russell                   Oxford                                    80
Partners                  Oxford                                    80
King                      Seattle                                   90
Kochhar                   Seattle                                   90
De Haan                   Seattle                                   90

6 rows selected.

In the above example, there is no need to issue a PRINT command to display the variable.

The following example creates some variables:

Keyboard icon
VARIABLE id NUMBER
VARIABLE txt CHAR (20)
VARIABLE myvar REFCURSOR

Enter VARIABLE with no arguments to list the defined variables:

Keyboard icon
VARIABLE

Screen icon
variable id
datatype NUMBER

variable txt
datatype CHAR(20)

variable myvar
datatype REFCURSOR

The following example lists a single variable:

Keyboard icon
VARIABLE txt

Screen icon
variable txt
datatype CHAR(20)

The following example illustrates producing a report listing individual salaries and computing the departmental salary cost for employees who earn more than $12,000 per month:

Keyboard icon
VARIABLE rc REFCURSOR
BEGIN
  OPEN :rc FOR SELECT DEPARTMENT_NAME, LAST_NAME, SALARY
  FROM EMP_DETAILS_VIEW
  WHERE SALARY > 12000
  ORDER BY DEPARTMENT_NAME, LAST_NAME;
END;
/

Screen icon
PL/SQL procedure successfully completed.

Keyboard icon
SET PAGESIZE 100 FEEDBACK OFF
TTITLE LEFT '*** Departmental Salary Bill ***' SKIP 2
COLUMN SALARY FORMAT $999,990.99 HEADING 'Salary'
COLUMN DEPARTMENT_NAME HEADING 'Department'
COLUMN LAST_NAME HEADING 'Employee'
COMPUTE SUM LABEL 'Subtotal:' OF SALARY ON DEPARTMENT_NAME
COMPUTE SUM LABEL 'Total:' OF SALARY ON REPORT
BREAK ON DEPARTMENT_NAME SKIP 1 ON REPORT SKIP 1
PRINT rc

Screen icon
*** Departmental Salary Bill ***

DEPARTMENT_NAME                Employee                        Salary
------------------------------ ------------------------- ------------
Executive                      De Haan                     $17,000.00
                               King                        $24,000.00
                               Kochhar                     $17,000.00
******************************                           ------------
Subtotal:                                                  $58,000.00

Marketing                      Hartstein                   $13,000.00
******************************                           ------------
Subtotal:                                                  $13,000.00

Sales                          Partners                    $13,500.00
                               Russell                     $14,000.00
******************************                           ------------
Subtotal:                                                  $27,500.00

                                                         ------------
Total:                                                     $98,500.00

The following example illustrates producing a report containing a CLOB column, and then displaying it with the SET LOBOFFSET command.

Assume you have already created a table named clob_tab which contains a column named clob_col of type CLOB. The clob_col contains the following data:

Remember to run the Departmental Salary Bill report each month. This report 
contains confidential information.

To produce a report listing the data in the col_clob column, enter

Keyboard icon
VARIABLE T CLOB
BEGIN
  SELECT CLOB_COL INTO :T FROM CLOB_TAB;
END;
/

Screen icon
PL/SQL PROCEDURE SUCCESSFULLY COMPLETED

To print 200 characters from the column clob_col, enter

Keyboard icon
SET LINESIZE 70
SET LONG 200
PRINT T

Screen icon
T
----------------------------------------------------------------------
Remember to run the Departmental Salary Bill report each month. This r
eport contains confidential information.

To set the printing position to the 21st character, enter

Keyboard icon
SET LOBOFFSET 21
PRINT T

Screen icon
T
----------------------------------------------------------------------
Departmental Salary Bill report each month. This report contains confi
dential information.

For more information on creating CLOB columns, see your Oracle9i SQL Reference.


Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 1996-2001, Oracle Corporation.

All Rights Reserved.
GRORACLE GRORACLE
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback