BC remote Oracle DBA - Call (800) 766-1884  
Oracle Consulting Oracle Training Development

Remote DBA

Remote DBA Plans  

Remote DBA Service

Remote DBA RAC

   
Remote DBA Oracle Home
Remote DBA Oracle Training
Remote DBA SQL Tuning Consulting
Remote DBA Oracle Tuning Consulting
Remote DBA Data Warehouse Consulting
Remote DBA Oracle Project Management
Remote DBA Oracle Security Assessment
Remote DBA Unix Consulting
Burleson Books
Burleson Articles
Burleson Web Courses
Burleson Qualifications
Oracle Links
Remote DBA Oracle Monitoring
Remote DBA Support Benefits
Remote DBA Plans & Prices
Our Automation Strategy
What We Monitor
Oracle Apps Support
Print Our Brochure
Contact Us (e-mail)
Oracle Job Opportunities
Oracle Consulting Prices





   

 

 

 

Remote DBA services

Remote DBA Support

Remote DBA RAC

Remote DBA Reasons

Remote Oracle Tuning

Remote DBA Links

Oracle DBA Support

Oracle DBA Forum

Oracle Disaster

Oracle Training

Oracle Tuning

Oracle Training

 Remote DBA SQL Server

Remote MSSQL Consulting

Oracle DBA Hosting

Oracle License Negotiation

 

 


 

 

 

 

   
  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
 

Notice that the variable v_hold is given an initial value of 1.  This is important because if it were not initialized it would start with a NULL value and the code would return NULL due to NULL math (refer to the Null Math section in Chapter 1, “Introduction to PL/SQL”).  Likewise if a value is initialized to 0, the code would be multiplying by zero (0) always resulting in zero (0).

 SQL> declare
  2    v_seed number := &numb;
  3    v_hold number;
  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: 4
!4 =      --(NULL)

SQL> declare
  2    v_seed number := &numb;
  3    v_hold number := 0;
  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:  4
!4 = 0   -- (multiplication by 0)


The above book excerpt is from:

Easy Oracle PL/SQL Programming

Get Started Fast with Working PL/SQL Code Examples

ISBN 0-9759135-7-3   

John Garmany 

http://www.rampant-books.com/book_2005_1_easy_plsql.htm

Remote DBA Service
 

Oracle Tuning Book

 

Advance SQL Tuning Book 

BC Oracle support

Oracle books by Rampant

Oracle monitoring software

 

 

 

 

 

 

BC Remote Oracle Support

Remote DBA

Remote DBA Services

Copyright © 1996 -  2013 by Burleson. All rights reserved.

Oracle® is the registered trademark of Oracle Corporation.