Skip to main content

Watch out for redundant code with WHILE loops

Generally, you should use a simple loop if you always want the body of the loop to execute at least once. You use a WHILE loop if you want to check before executing the body the first time. Since the WHILE loop performs its check “up front,” the variables in the boundary expression must be initialized. The code to initialize is often the same code needed to move to the next iteration in the WHILE loop. This redundancy creates a challenge in both debugging and maintaining the code: how do you remember to look at and update both?

If you find yourself writing and running the same code before the WHILE loop and at end of the WHILE loop body, consider switching to a simple loop.

Here's an example.
I write a procedure to calculate overdue charges for books; the maximum fine to be charged is $10, and I will stop processing when there are no overdue books for a given date. Here is my first attempt at the procedure body:

DECLARE
   l_fine PLS_INTEGER := 0;
   l_date DATE := SYSDATE;
   l_overdue_count NUMBER;
BEGIN
   l_overdue_count :=
      overdue_pkg.countem (
         borrower_id => borrower_in,
         l_date);
  
   WHILE (l_overdue_count > 0 AND l_fine < 10)
   LOOP
      update_fine_info (l_date, l_one_day_fine);

      l_fine := l_fine + l_one_day_fine;
      l_date := l_date + 1;

      l_overdue_count :=
         overdue_pkg.countem (
            borrower_id => borrower_in,
            l_date);
   END LOOP;
END;   

As is readily apparent, I duplicate the assignments of values to l_overdue_count. I would be far better off rewriting this code as follows:

DECLARE
   l_fine PLS_INTEGER := 0;
   l_date DATE := SYSDATE;
   l_overdue_count NUMBER;
BEGIN
   LOOP
      EXIT WHEN
        (l_overdue_count <= 0 OR l_fine >= 10)
     
      update_fine_info (l_date, l_one_day_fine);
     
      l_fine := l_fine + l_one_day_fine;
     
      l_date := l_date + 1;

      l_overdue_count :=
         overdue_pkg.countem (
            borrower_id => borrower_in,
            l_date);
   END LOOP;
END;   


By paying close attention to your loop construction, you can avoid redundant code, always bad news in a program, since it increases maintenance costs and the chance of introducing bugs into your code.

Comments

  1. Great tip Steven!

    There is a subtle difference between the two versions though... In your second example, l_overdue_count = NULL in the first iteration. It requires that one knows how nulls are handled in calculations and boolean evaluations, e.g:

    (null <= 0) evaluates to null
    (null or a) evaluates to a

    But in the case of AND
    (null and false) = false
    (null and true) = false
    This last one can surprise you if you're not paying attention ;)

    ReplyDelete
  2. @Rop, thanks for writing, but I need some clarification. When I execute this block:

    DECLARE
    PROCEDURE bplstr (str IN VARCHAR2, val IN BOOLEAN)
    IS
    BEGIN
    DBMS_OUTPUT.put_line (
    str
    || ' - '
    || CASE val
    WHEN TRUE THEN 'TRUE'
    WHEN FALSE THEN 'FALSE'
    ELSE 'NULL'
    END);
    END bplstr;
    BEGIN
    bplstr ('(NULL AND FALSE)', (NULL AND FALSE));
    bplstr ('(NULL AND TRUE)', (NULL AND TRUE));
    bplstr ('(NULL OR FALSE)', (NULL OR FALSE));
    bplstr ('(NULL OR TRUE)', (NULL OR TRUE));
    END;
    /

    I see:

    (NULL AND FALSE) - FALSE
    (NULL AND TRUE) - NULL
    (NULL OR FALSE) - NULL
    (NULL OR TRUE) - TRUE

    What do you see?

    ReplyDelete
  3. *Sigh* of course you're right... my output is the same as yours. I fell into my own trap while trying to be smart.

    I only used an if/then/else, like this:

    if (null and true) then
    dbms_output.put_line('true');
    else
    dbms_output.put_line('false');
    end if;

    This outputs 'false' when the actual value is null.
    Well... it shows how difficult it is to evaluate null conditions ;)

    ReplyDelete

Post a Comment

Popular posts from this blog

Quick Guide to User-Defined Types in Oracle PL/SQL

A Twitter follower recently asked for more information on user-defined types in the PL/SQL language, and I figured the best way to answer is to offer up this blog post. PL/SQL is a strongly-typed language . Before you can work with a variable or constant, it must be declared with a type (yes, PL/SQL also supports lots of implicit conversions from one type to another, but still, everything must be declared with a type). PL/SQL offers a wide array of pre-defined data types , both in the language natively (such as VARCHAR2, PLS_INTEGER, BOOLEAN, etc.) and in a variety of supplied packages (e.g., the NUMBER_TABLE collection type in the DBMS_SQL package). Data types in PL/SQL can be scalars, such as strings and numbers, or composite (consisting of one or more scalars), such as record types, collection types and object types. You can't really declare your own "user-defined" scalars, though you can define subtypes  from those scalars, which can be very helpful from the p

The differences between deterministic and result cache features

 EVERY once in a while, a developer gets in touch with a question like this: I am confused about the exact difference between deterministic and result_cache. Do they have different application use cases? I have used deterministic feature in many functions which retrieve data from some lookup tables. Is it essential to replace these 'deterministic' key words with 'result_cache'?  So I thought I'd write a post about the differences between these two features. But first, let's make sure we all understand what it means for a function to be  deterministic. From Wikipedia : In computer science, a deterministic algorithm is an algorithm which, given a particular input, will always produce the same output, with the underlying machine always passing through the same sequence of states.  Another way of putting this is that a deterministic subprogram (procedure or function) has no side-effects. If you pass a certain set of arguments for the parameters, you will always get

How to Pick the Limit for BULK COLLECT

This question rolled into my In Box today: In the case of using the LIMIT clause of BULK COLLECT, how do we decide what value to use for the limit? First I give the quick answer, then I provide support for that answer Quick Answer Start with 100. That's the default (and only) setting for cursor FOR loop optimizations. It offers a sweet spot of improved performance over row-by-row and not-too-much PGA memory consumption. Test to see if that's fast enough (likely will be for many cases). If not, try higher values until you reach the performance level you need - and you are not consuming too much PGA memory.  Don't hard-code the limit value: make it a parameter to your subprogram or a constant in a package specification. Don't put anything in the collection you don't need. [from Giulio Dottorini] Remember: each session that runs this code will use that amount of memory. Background When you use BULK COLLECT, you retrieve more than row with each fetch,