HomeMogDBMogDB StackUqbar
v1.1

Documentation:v1.1

Supported Versions:

Basic Statements

During PL/SQL programming, you may define some variables, assign values to variables, and call other stored procedures. This chapter describes basic PL/SQL statements, including variable definition statements, value assignment statements, call statements, and return statements.

img NOTE: You are advised not to call the SQL statements containing passwords in the stored procedures because authorized users may view the stored procedure file in the database and password information is leaked. If a stored procedure contains other sensitive information, permission to access this procedure must be configured, preventing information leakage.

Define Variable

This section describes the declaration of variables in the PL/SQL and the scope of this variable in codes.

Variable Declaration

For details about the variable declaration syntax, see Figure 1.

Figure 1 declare_variable::=

declare_variable

The above syntax diagram is explained as follows:

  • variable_name indicates the name of a variable.
  • type indicates the type of a variable.
  • value indicates the initial value of the variable. (If the initial value is not given, NULL is taken as the initial value.) value can also be an expression.

Examples

mogdb=# DECLARE
    emp_id  INTEGER := 7788; -- Define a variable and assign a value to it.
BEGIN
    emp_id := 5*7784; -- Assign a value to the variable.
END;
/

In addition to the declaration of basic variable types, %TYPE and %ROWTYPE can be used to declare variables related to table columns or table structures.

%TYPE Attribute

%TYPE declares a variable to be of the same data type as a previously declared variable (for example, a column in a table). For example, if you want to define a my_name variable whose data type is the same as the data type of the firstname column in the employee table, you can define the variable as follows:

my_name employee.firstname%TYPE

In this way, you can declare my_name without the need of knowing the data type of firstname in employee, and the data type of my_name can be automatically updated when the data type of firstname changes.

%ROWTYPE Attribute

%ROWTYPE declares data types of a set of data. It stores a row of table data or results fetched from a cursor. For example, if you want to define a set of data with the same column names and column data types as the employee table, you can define the data as follows:

my_employee employee%ROWTYPE

Scope of a Variable

The scope of a variable indicates the accessibility and availability of the variable in code block. In other words, a variable takes effect only within its scope.

  • To define a function scope, a variable must declare and create a BEGIN-END block in the declaration section. The necessity of such declaration is also determined by block structure, which requires that a variable has different scopes and lifetime during a process.
  • A variable can be defined multiple times in different scopes, and inner definition can cover outer one.
  • A variable defined in an outer block can also be used in a nested block. However, the outer block cannot access variables in the nested block.

Assignment Statements

Syntax

Figure 2 shows the syntax diagram for assigning a value to a variable.

Figure 2 assignment_value::=

assignment_value

The above syntax diagram is explained as follows:

  • variable_name indicates the name of a variable.
  • value can be a value or an expression. The type of value must be compatible with the type of variable_name.

Example

mogdb=# DECLARE
    emp_id  INTEGER := 7788; --Assignment
BEGIN
    emp_id := 5; --Assignment
    emp_id := 5*7784;
END;
/

Call Statement

Syntax

Figure 3 shows the syntax diagram for calling a clause.

Figure 3 call_clause::=

call_clause

The above syntax diagram is explained as follows:

  • procedure_name specifies the name of a stored procedure.
  • parameter specifies the parameters for the stored procedure. You can set no parameter or multiple parameters.

Example

-- Create the stored procedure proc_staffs:
mogdb=# CREATE OR REPLACE PROCEDURE proc_staffs
(
section     NUMBER(6),
salary_sum out NUMBER(8,2),
staffs_count out INTEGER
)
IS
BEGIN
SELECT sum(salary), count(*) INTO salary_sum, staffs_count FROM hr.staffs where section_id = section;
END;
/

-- Invoke a stored procedure proc_return:
mogdb=# CALL proc_staffs(2,8,6);

-- Delete a stored procedure:
mogdb=# DROP PROCEDURE proc_staffs;
Copyright © 2011-2024 www.enmotech.com All rights reserved.