[ Team LiB ] Previous Section Next Section

1.5 Variables and Program Data

PL/SQL programs are normally used to manipulate database information. You commonly do this by declaring variables and data structures in your programs, and then working with that PL/SQL-specific data.

A variable is a named instantiation of a data structure declared in a PL/SQL block (either locally or in a package). Unless you declare a variable as a CONSTANT, its value can be changed at any time in your program.

The following table summarizes the different types of program data:

Type

Description

Scalar

Variables made up of a single value, such as a number, date, or Boolean

Composite

Variables made up of multiple values, such as a record or a collection

Reference

Pointers to values

LOB

Variables containing large object (LOB) locators

1.5.1 Scalar Datatypes

Scalar datatypes divide into four families: number, character, datetime, and Boolean.

1.5.1.1 Numeric datatypes

Numeric datatypes are further divided into decimal, binary integer, and PLS_INTEGER storage types.

Decimal numeric datatypes store fixed and floating-point numbers of just about any size. They include NUMBER, DEC, DECIMAL, NUMERIC, FLOAT, REAL, and DOUBLE PRECISION. The maximum precision of a variable with type NUMBER is 38 digits, which yields a range of values from 1.0E-129 through 9.999E125. (This range of numbers would include the mass of an electron over the mass of the universe or the size of the universe in angstroms.)

Variables of type NUMBER can be declared with precision and scale, as follows:

NUMBER(precision, scale)

where precision is the number of digits, and scale is the number of digits to the right (positive scale) or left (negative scale) of the decimal point at which rounding occurs. Legal values for scale range from -84 to 127. The following table shows examples of precision and scale:

Declaration

Assigned value

Stored value

NUMBER

6.02

6.02

NUMBER(4)

8675

8675

NUMBER(4)

8675309

Error

NUMBER(12,5)

3.14159265

3.14159

NUMBER(12,-5)

8675309

8700000

Binary integer numeric datatypes store whole numbers. They include BINARY_INTEGER, INTEGER, INT, SMALLINT, NATURAL, NATURALN, POSITIVE, POSITIVEN, and SIGNTYPE. Binary integer datatypes store signed integers in the range of -231 + 1 to 231 - 1. The subtypes include NATURAL (0 through 231) and POSITIVE (1 through 231) together with the NOT NULL variations NATURALN and POSITIVEN. SIGNTYPE is restricted to three values (-1, 0, 1).

PLS_INTEGER datatypes have the same range as the BINARY_INTEGER datatype, but use machine arithmetic instead of library arithmetic, so are slightly faster for computation-heavy processing.

The following table lists the PL/SQL numeric datatypes with ANSI and IBM compatibility. In this table:

  • prec is the precision for the subtype.

  • scale is the scale of the subtype.

  • binary is the binary precision of the subtype.

PL/SQL datatype

Compatibility

Oracle RDBMS datatype

DEC(prec,scale)

ANSI

NUMBER(prec,scale)

DECIMAL(prec,scale)

IBM

NUMBER(prec,scale)

DOUBLE PRECISION

ANSI

NUMBER

FLOAT(binary)

ANSI, IBM

NUMBER

INT

ANSI

NUMBER(38)

INTEGER

ANSI, IBM

NUMBER(38)

NUMERIC(prec,scale)

ANSI

NUMBER(prec,scale)

REAL

ANSI

NUMBER

SMALLINT

ANSI, IBM

NUMBER(38)

1.5.1.2 Character datatypes

Character datatypes store alphanumeric text and are manipulated by character functions. As with the numeric family, there are several subtypes in the character family, shown in the following table:

Family

Description

CHAR

Fixed-length alphanumeric strings. Valid sizes are 1 to 32767 bytes (which is larger than the Oracle database limit of 4000).

VARCHAR2

Variable-length alphanumeric strings. Valid sizes are 1 to 32767 bytes (which is larger than the Oracle database limit of 4000).

LONG

Variable-length alphanumeric strings. Valid sizes are 1 to 32760 bytes. LONG is included primarily for backward compatibility. CLOB is the preferred datatype for large character strings.

RAW

Variable-length binary strings. Valid sizes are 1 to 32767 bytes (which is larger than the Oracle database limit of 2000). RAW data do not undergo character set conversion when selected from a remote database.

LONG RAW

Variable-length binary strings. Valid sizes are 1 to 32760 bytes. LONG RAW is included primarily for backward compatibility. BLOB and BFILE are the preferred datatypes for large binary data.

ROWID

Fixed-length binary data. Every row in a database has a physical address or ROWID. A ROWID has four parts in base 64:

OOOOOOFFFBBBBBBRRR

where:

OOOOOO is the object number.

FFFF is the absolute or relative file number.

BBBBBBBB is the block number within the file.

RRRR is the row number within the block.

UROWID

Universal ROWID. Variable-length hexadecimal string depicting a logical, physical, or non-Oracle row identifier. Valid sizes are up to 4000 bytes.

1.5.1.3 Datetime datatypes

Oracle expanded support for datetime data in Oracle9i by introducing an assortment of new datatypes. The datetime datatypes are DATE (the only datetime datatype pre-Oracle9i), TIMESTAMP, TIMESTAMP WITH TIME ZONE, and TIMESTAMP WITH LOCAL TIME ZONE. The two interval datatypes, also new to Oracle9i, are INTERVAL YEAR TO MONTH and INTERVAL DAY TO SECOND.

DATE values are fixed-length, date-plus-time values. The DATE datatype can store dates from January 1, 4712 B.C. to December 31, 9999 A.D. Each DATE includes the century, year, month, day, hour, minute, and second. Sub-second granularity is not supported via the DATE datatype; use one of the TIMESTAMP datatypes instead. The time portion of a DATE defaults to midnight (12:00:00 AM) if it is not included explicitly.

TIMESTAMP values store date and time to sub-second granularity. The sub-second precision (the number of digits to the right of the decimal) either defaults or is set to 0 through 9 digits by declaration, as in:

DECLARE
  mytime_declared TIMESTAMP(9);
  mytime_default  TIMESTAMP;

The default precision is 6 digits of precision to the right of the decimal.

TIMESTAMP WITH TIME ZONE values store date and time values like a TIMESTAMP but also store the hourly offset from UTC (Coordinated Universal Time, which is essentially equivalent to Greenwich Mean Time). As with TIMESTAMP, the sub-second precision is 0 to 9 digits, either declared or inherited from the default 6 digits of precision.

DECLARE
  mytime_declared TIMESTAMP(9) WITH TIME ZONE;
  mytime_default  TIMESTAMP WITH TIME ZONE;

TIMESTAMP WITH LOCAL TIME ZONE values store date and time values together with the UTC offset, like a TIMESTAMP WITH TIME ZONE. The principal difference between these timestamp datatypes occurs when values are saved to or retrieved from a database table. TIMESTAMP WITH LOCAL TIME ZONE values are converted to the database time zone and saved without an offset. The values retrieved from the database table are converted from the database time zone to the session's time zone.

The offset from UTC for both TIMESTAMP WITH TIME ZONE and TIMESTAMP WITH LOCAL TIME ZONE can be hours and minutes or a time zone region (found in the V$TIMEZONE_NAMES data dictionary view) with the optional daylight savings time name (also found in V$TIMEZONE_NAMES). For example:

ALTER SESSION SET NLS_TIMESTAMP_TZ_FORMAT=
   'DD-Mon-YYYY HH24:MI:SS.FF TZR';
DECLARE
   my_tswtz    TIMESTAMP(4) WITH TIME ZONE;
BEGIN
   my_tswtz := '31-JUL-02 07:32:45.1234 US/Pacific';

INTERVAL YEAR TO MONTH values store a period of time in years and months:

DECLARE
  myy2m INTERVAL YEAR TO MONTH;
BEGIN
  myy2m := INTERVAL '1-6' YEAR TO MONTH; 

INTERVAL DAY TO SECOND values store a period of time in days, hours, minutes, seconds, and fractional seconds:

DECLARE
  myd2s INTERVAL DAY TO SECOND;
BEGIN
  myd2s := INTERVAL '2 10:32:15.678' DAY TO SECOND;
1.5.1.4 Boolean datatype

The BOOLEAN datatype can store one of only three values: TRUE, FALSE, or NULL. BOOLEAN variables are usually used in logical control structures such as IF...THEN or LOOP statements.

The following truth tables show the results of logical AND, OR, and NOT operations with PL/SQL's three-value Boolean model:

AND

TRUE

FALSE

NULL

TRUE

TRUE

FALSE

NULL

FALSE

FALSE

FALSE

FALSE

NULL

NULL

FALSE

NULL

OR

TRUE

FALSE

NULL

TRUE

TRUE

TRUE

TRUE

FALSE

TRUE

FALSE

NULL

NULL

TRUE

NULL

NULL

NOT (TRUE)

NOT (FALSE)

NOT (NULL)

FALSE

TRUE

NULL

1.5.2 NLS Character Datatypes

The standard WE8MSWIN1252 or WE8ISO8859P2 character set does not support some languages, such as Chinese and Greek. To support a secondary character set, Oracle allows two character sets in a database—the database character set and the national character set (NLS).

The two NLS datatypes, NCHAR and NVARCHAR2, are used to represent data in the national character set. NCHAR values are fixed-length character data; the maximum length is 32767 bytes. NVARCHAR2 values are variable-length character data; the maximum length is also 32767 bytes.

1.5.3 LOB Datatypes

PL/SQL supports a number of large object (LOB) datatypes, which can store objects of up to four gigabytes of data. Unlike the scalar datatypes, variables declared for LOBs use locators, or pointers to the actual data. LOBs are manipulated in PL/SQL using the built-in package DBMS_LOB. The LOB datatypes are:

BFILE

File locators pointing to read-only large binary objects in operating system files. With BFILEs, the large objects are outside the database.

BLOB

LOB locators that point to large binary objects inside the database.

CLOB

LOB locators that point to large character (alphanumeric) objects inside the database.

NCLOB

LOB locators that point to large national character set objects inside the database.

1.5.4 Implicit Datatype Conversions

Whenever PL/SQL detects that a datatype conversion is necessary, it attempts to change the values as required to perform the operation. Figure 2 shows what types of implicit conversions PL/SQL can perform.

Figure 1-2. Implicit conversions performed by PL/SQL
figs/sqlPR2.02.gif

1.5.5 NULLs in PL/SQL

PL/SQL represents unknown or inapplicable values as NULL values. Because a NULL is unknown, a NULL is never equal or not equal to anything (including another NULL value). In addition, most functions return a NULL when passed a NULL argument—the notable exceptions are NVL, NVL2, CONCAT, and REPLACE. You cannot check for equality or inequality to NULL; therefore, you must use the IS NULL or IS NOT NULL syntax to check for NULL values.

Here is an example of the IS NULL syntax used to check the value of a variable:

BEGIN
   IF myvar IS NULL
   THEN
      ...

1.5.6 Declaring Variables

Before you can use a variable, you must first declare it in the declaration section of your PL/SQL block or in a package as a global. When you declare a variable, PL/SQL allocates memory for the variable's value and names the storage location so that the value can be retrieved and changed. The syntax for a variable declaration is:

variable_name datatype [CONSTANT] [NOT NULL] 
   [{ := | DEFAULT } initial_value]
1.5.6.1 Constrained declarations

The datatype in a declaration can be constrained or unconstrained. Constrained datatypes have a size, scale, or precision limit that is less than the unconstrained datatype. For example:

total_sales    NUMBER(15,2);  -- Constrained.
emp_id         VARCHAR2(9);   -- Constrained.
company_number NUMBER;        -- Unconstrained.
book_title     VARCHAR2;      -- Not valid.

Constrained declarations require less memory than unconstrained declarations. Not all datatypes can be specified as unconstrained. You cannot, for example, declare a variable to be of type VARCHAR2. You must always specify the maximum size of a variable-length string.

1.5.6.2 Constants

The CONSTANT keyword in a declaration requires an initial value and does not allow that value to be changed. For example:

min_order_qty   NUMBER(1) CONSTANT := 5;
1.5.6.3 Default values

Whenever you declare a variable, it is assigned a default value of NULL. Initializing all variables is distinctive to PL/SQL; in this way, PL/SQL differs from languages such as C and Ada. If you want to initialize a variable to a value other than NULL, you do so in the declaration with either the assignment operator (:=) or the DEFAULT keyword:

counter   BINARY_INTEGER := 0;
priority  VARCHAR2(8)    DEFAULT 'LOW';

A NOT NULL constraint can be appended to the variable's datatype declaration to indicate that NULL is not a valid value. If you add the NOT NULL constraint, you must explicitly assign an initial value for that variable.

1.5.7 Anchored Declarations

Use the %TYPE attribute to anchor the datatype of a scalar variable to either another variable or to a column in a database table or view. Use %ROWTYPE to anchor a record's declaration to a cursor or table (see Section 1.11 for more detail on the %ROWTYPE attribute).

The following block shows several variations of anchored declarations:

DECLARE
   tot_sales NUMBER(20,2);
   -- Anchor to a PL/SQL variable.
   monthly_sales tot_sales%TYPE;

   -- Anchor to a database column.
   v_ename employee.last_name%TYPE;

   CURSOR mycur IS
      SELECT * FROM employee;

   -- Anchor to a cursor.
   myrec mycur%ROWTYPE;

The NOT NULL clause on a variable declaration (but not on a database column definition) follows the %TYPE anchoring and requires anchored declarations to have a default in their declaration. The default value for an anchored declaration can be different from that for the base declaration:

tot_sales      NUMBER(20,2) NOT NULL DEFAULT 0;
monthly_sales  tot_sales%TYPE DEFAULT 10;

1.5.8 Programmer-Defined Subtypes

PL/SQL allows you to define unconstrained scalar subtypes. An unconstrained subtype provides an alias to the original underlying datatype; for example:

CREATE OR REPLACE PACKAGE std_types
IS
   -- Declare standard types as globals.
   SUBTYPE dollar_amt_t IS NUMBER;
END std_types;

CREATE OR REPLACE PROCEDURE process_money
IS
   -- Use the global type declared above.
   credit std_types.dollar_amt_t;
   ...

A constrained subtype limits or constrains the new datatype to a subset of the original datatype. For example, POSITIVE is a constrained subtype of BINARY_INTEGER. The declaration for POSITIVE in the STANDARD package is:

SUBTYPE POSITIVE IS BINARY_INTEGER RANGE 1..2147483647;

You can define your own constrained subtypes in your programs:

PACKAGE std_types
IS
   SUBTYPE currency_t IS NUMBER (15, 2);

END;
    [ Team LiB ] Previous Section Next Section