You can declare a storage space for a specified data type and name the storage location so that it can be referenced later.
You must declare an object before you can reference it. A declaration can be made in the declaration section of a block, subprogram, or package.
Applicability
This topic applies only to OceanBase Database Enterprise Edition. OceanBase Database Community Edition provides only the MySQL mode.
NOT NULL constraint
You can apply the NOT NULL constraint to a scalar variable or constant, or a scalar component of a composite variable or constant.
The NOT NULL constraint prevents a null value from being assigned to the object. The NOT NULL attribute of an object can be explicitly or implicitly specified.
If you specify the NOT NULL constraint for a scalar variable during its declaration, you must initialize the variable with a value (the default initial value of a scalar variable is NULL).
PL considers any zero-length string to be a NULL value, including the return values of character functions and BOOLEAN expressions.
Declare a variable
When you declare a variable, you must specify the name and data type of the variable. You can also specify an initial value for the variable of most data types.
The name of the variable must be an effective user-defined identifier. Any PL data type can be specified as the data type. PL data types include all SQL data types. The data type can be a scalar type or a composite type.
Declare a constant
A constant is used to store an invariant value.
The information specified in a variable declaration also applies to a constant declaration, but a constant declaration requires the CONSTANT keyword and the initial value of the constant (which is also the permanent value of the constant).
Initial values of variables and constants
In a variable declaration, the initial value is optional unless the NOT NULL constraint is specified. In a constant declaration, the initial value is mandatory.
If the declaration is made in a block or subprogram, the initial value is assigned to the variable or constant each time the block or subprogram is executed. If the declaration is made in the SPECIFICATION section of a package, the initial value is assigned to the variable or constant in each session, regardless of whether the variable or constant is public or private.
You can use the assignment operator (:=) or the DEFAULT keyword followed by an expression to specify an initial value. The expression can contain the initial values of previously declared constants and the initial values or the current values of previously initialized variables. If an initial value is not specified for a variable, assign a value to the variable before you use it.
Here is an example:
obclient> DECLARE
pi CONSTANT NUMBER := 3.14159;
radius NUMBER NOT NULL := 1;
area NUMBER := (pi * radius**2);
BEGIN
DBMS_OUTPUT.PUT_LINE('The area of the circle is: '||area);
END;
/
Query OK, 0 rows affected
The area of the circle is: 3.14159
Declare with %TYPE
You can declare an object that has the same data type as a previously declared variable or column without knowing the data type.
The advantages of using the %TYPE attribute are as follows:
The data type of the referenced database column can be unknown.
The variable type will change as the data type of the referenced column changes.
The syntax is as follows:
referencing_item referenced_item%TYPE;
The referenced item will be inherited by the referencing item:
Data type and size
Constraints (excluding those of the column)
The referenced item does not inherit the initial value of the referencing item. Therefore, if the referencing item specifies or inherits the NOT NULL constraint, you must specify an initial value for the referencing item.
%TYPE is particularly useful for declaring variables to store database values. The syntax for declaring a variable that has the same data type as a column is as follows:
variable_name table_name.column_name%TYPE;
Here is an example:
obclient> DECLARE
firstname VARCHAR(30) NOT NULL := 'San';
lastname firstname%TYPE := 'Zhang';
BEGIN
DBMS_OUTPUT.PUT_LINE('firstname=' || firstname);
DBMS_OUTPUT.PUT_LINE('lastname=' || lastname);
END;
/
Query OK, 0 rows affected
firstname=San
lastname=Zhang
In this example, the lastname variable inherits the data type, size, and NOT NULL constraint of the firstname variable. Since the lastname variable does not inherit the initial value of the firstname variable, an initial value must be specified for the lastname variable (no more than 30 characters).