Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 
 

PL/SQL FOR Loop tips

Oracle Tips by Burleson

The PL/SQL FOR Loop

The FOR loop  executes for a specified number of times, defined in the loop definition.  Because the number of loops is specified, the overhead of checking a condition to exit is eliminated.  The number of executions is defined in the loop definition as a range from a start value to an end value (inclusive).  The integer index in the FOR loop starts at the start value and increments by one (1) for each loop until it reaches the end value. 

SQL> begin
  2    for idx in 2..5 loop
  3      dbms_output.put_line (idx);
  4    end loop;
  5  end;
  6  /
2
3
4

PL/SQL procedure successfully completed.

In the example below a variable idx is defined, assigning it the value 100.  When the FOR loop executes, the variable idx is also defined as the index for the FOR loop.  The original variable idx goes out of scope when the FOR loop defines its index variable.  Inside the FOR loop, the idx variable is the loop index.  Once the FOR loop terminates, the loop index goes out of scope and the original idx variable is again in scope.

SQL> declare
  2    idx number := 100;
  3  begin
  4    dbms_output.put_line (idx);
  5    for idx in 2..5 loop
  6      dbms_output.put_line (idx);
  7    end loop;
  8    dbms_output.put_line (idx);
  9  end;
 10  /
100
2
3
4
5
100 

PL/SQL procedure successfully completed.

You can use the loop index inside the loop, but you can not change it.  If you want to loop by an increment other than one, you will have to do so programmatically as the FOR loop will only increment the index by one. 

SQL> begin
  2    for i in 4 .. 200 loop
  3     
i := i + 4;
  4    end loop;
  5  end;
  6  /
    i := i + 4;
    *
ERROR at line 3:
ORA-06550: line 3, column 5:
PLS-00363: expression 'I' cannot be used as an assignment target
ORA-06550: line 3, column 5:
PL/SQL: Statement ignored

The loop index start and stop values can be expressions or variables.  They are evaluated once at the start of the loop to determine the number of loop iterations.  If their values change during the loop processing, it does not impact the number of iterations.

SQL> declare
  2    n_start number := 3;
  3    n_stop  number := 6;
  4  begin
  5    for xyz in n_start .. n_stop loop
  6      n_stop := 100;
  7      dbms_output.put_line (xyz);
  8    end loop;
  9  end;
 10  /
3
4
5
6

PL/SQL procedure successfully completed.

Line 6 changes the stop value, setting it to 100.  But the loop still terminates at the value of 6.  The loop index start and stop values are always defined from lowest to highest.  If you want the index to count down use the REVERSE key word.

SQL> begin
  2    for num in 4 .. 7 loop
  3      dbms_output.put_line (num);
  4    end loop;
  5
  6    for num in reverse 4 .. 7 loop
  7      dbms_output.put_line (num);
  8    end loop;
  9
 10    for num in 7 .. 4 loop
 11      dbms_output.put_line (num);
 12    end loop;
 13  end;
 14  /
4
5
6
7
7
6
5

PL/SQL procedure successfully completed.

Notice that the third FOR loop COMPILED BUT DID NOT EXECUTE!  The FOR loop calculated the number of loop iterations and got a negative number, therefore the loop count was zero.

In the next example a FOR loop is used to calculate the factorial of a number.  A factorial value is commonly used to determine all possible values for a number and is defined as x*(x-1)*(x-2)?.(0) = !x.

!8 = 8*7*6*5*4*3*2*1 = 40320

SQL> declare
  2    v_seed number := &numb;
  3    v_hold number := 1;
  4  begin
  5    for i in reverse 1 .. v_seed loop
  6      v_hold := v_hold * i;
  7    end loop;
  8    dbms_output.put_line ('!'||v_seed||' = '||v_hold);
  9  end;
 10  / 

Enter value for numb: 8
!8 = 40320 

SQL> /
Enter value for numb: 4
!4 = 24
 

Related PL/SQL FOR Loop Articles:

The FOR loop runs one or more executable statements placed with in its loop structure while the loop index value is between the lower bound and the upper bound.

 

The below prototype defines the basic structure of the FOR loop.

 

For <loop_index> in [Reverse] <lower_bound> .. <upper_bound> loop

<Executable statements>;

End loop <loop_index>;

% Note: Reverse keyword is optional in the FOR loop’s structure. The <loop_index> placed after the END LOOP syntax is optional and it is meant for identifying a particular loop’s end with ease.

The <lower_bound> value cannot be greater than the <upper_bound> value, else the loop will not run even once.

 

The <upper_bound> value cannot be lower the <lower_bound> value, else the loop will not run even once.

 

% Note: If the <lower_bound> and the <upper_bound> values are equal, the FOR loop executes only once irrespective of its bound value.

While the reverse keyword is placed, the <loop_index> value starts at the <lower_bound> and increments itself by 1 for each iteration of the loop until it reaches the <upper_bound>.

 

While the reverse keyword is not placed, the <loop_index> value starts at the <upper_bound> and decrements itself by 1 for each iteration of the loop until it reaches the <lower_bound>.

PL/SQL FOR loop tips

The below script runs the loop for 5 times starting from the lower bound value 1 incrementing itself by 1 until it reaches the upper bound value 5.

 

1.  BEGIN

2.  FOR loop_index IN 1..5

3.  LOOP

4.  dbms_output.put_line(loop_index);

5.  END LOOP loop_index;

6.  END;

7.  /

 

Result:

 

1

2

3

4

5

 

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as 1 and upper bound value as 5

4

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

5

End of the FOR loop

6,7

End of the execution section of the block

 

For loop with REVERSE keyword

The below script runs the loop for 5 times starting from the upper bound value 5 decrementing itself by 1 until it reaches the lower bound value 1.

 

1.  BEGIN

2.  FOR loop_index IN reverse 1 .. 5

3.  LOOP

4.  dbms_output.put_line(loop_index);

5.  END LOOP loop_index;

6.  END;

7.  /

 

Result:

 

5

4

3

2

1

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as 1, upper bound value as 5 and reverse keyword placed.

4

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

5

End of the FOR loop

6,7

End of the execution section of the block

FOR loop with decimal loop index value

The below FOR loop has decimal values for its lower bound and upper bound values. These loop index values are rounded off to its nearest value and then the loop starts its execution. In the below example, the lower bound value of 1.1 is rounded off to 1 and the upper bound value of 5.5 is rounded off to 6, thus the loop runs for 6 times starting from the rounded lower bound value of 1 through the rounded upper bound value of 6.

 

1.  BEGIN

2.  FOR loop_index IN 1.1 .. 5.5

3.  LOOP

4.  dbms_output.put_line(loop_index);

5.  END LOOP loop_index;

6.  END;

7.  /

 

Result:

 

1

2

3

4

5

6

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as 1.1 and upper bound value as 5.5

4

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

5

End of the FOR loop

6,7

End of the execution section of the block

FOR loop with non-numeric loop index value

The loop index is implicitly created with PLS_INTEGER data type and when the lower bound and the upper bound values of a FOR loop are of non-numeric literals, the loop’s execution fails resulting in an exception. The below example immediately raises the predefined exception VALUE_ERROR when executed.

 

1.  BEGIN

2.  FOR loop_index IN 'A' .. 'D'

3.  LOOP

4.  dbms_output.put_line(loop_index);

5.  END LOOP loop_index;

6.  END;

7.  /

 

Error report:

ORA-06502: PL/SQL: numeric or value error: character to number conversion error

ORA-06512: at line 2

06502. 00000 - "PL/SQL: numeric or value error%s"

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as ‘A’ and upper bound value as ‘D’

4

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

5

End of the FOR loop

6,7

End of the execution section of the block

 

FOR loop index

The loop index value has its scope inside the FOR loop’s structure only and when it is accessed outside its structure, the loop fails with the below compilation error.

 

1.  BEGIN

2.  FOR loop_index IN 1 .. 5

3.  LOOP

4.  dbms_output.put_line(loop_index);

5.  END LOOP loop_index;

6.  dbms_output.put_line(loop_index);

7.  END;

8.  /

 

Error report:

ORA-06550: line 6, column 24:

PLS-00201: identifier 'LOOP_INDEX' must be declared

ORA-06550: line 6, column 3:

PL/SQL: Statement ignored

06550. 00000 - "line %s, column %s:\n%s"

*Cause:   Usually a PL/SQL compilation error.

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as 1 and upper bound value as 5

4

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

5

End of the FOR loop

6

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

7,8

End of the execution section of the block

 

 

The statements inside the loop can access the loop index’s value but it can never be assigned with any value. Once the loop’s execution is completely done, the loop index’s value is reset to Null. The below example fails with an error when its loop index          is used as an assignment target.

 

1.  BEGIN

2.  FOR loop_index IN 1 .. 5

3.  LOOP

4.  loop_index:=10;

5.  dbms_output.put_line(loop_index);

6.  END LOOP loop_index;

7.  END;

8.  /

 

Error report:

ORA-06550: line 4, column 5:

PLS-00363: expression 'LOOP_INDEX' cannot be used as an assignment target

ORA-06550: line 4, column 5:

PL/SQL: Statement ignored

06550. 00000 - "line %s, column %s:\n%s"

*Cause:   Usually a PL/SQL compilation error.

Script Explanation

Line no.

Description

1

Start of the execution section of the block

2,3

Start of the FOR loop statement with lower bound value as 1 and upper bound value as 5

4

The loop_index is assigned to the value 10.

5

The loop index value is printed using the DBMS_OUTPUT.PUT_LINE procedure

6

End of the FOR loop

7,8

End of the execution section of the block

 


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational