Skip to main content

Another reminder of the elegance and brevity of CASE expressions

Building a script for an upcoming PL/SQL Challenge quiz, I wrote a nested procedure as follows:

   PROCEDURE show_cursor_status
   IS
   BEGIN
      IF all_in_one_cur%ISOPEN
      THEN
         DBMS_OUTPUT.put_line ('all_in_one_cur is still open');
      ELSE
         DBMS_OUTPUT.put_line ('all_in_one_cur is closed');
      END IF;

      IF department_cur%ISOPEN
      THEN
         DBMS_OUTPUT.put_line ('department_cur is still open');
      ELSE
         DBMS_OUTPUT.put_line ('department_cur is closed');
      END IF;

      IF employee_cur%ISOPEN
      THEN
         DBMS_OUTPUT.put_line ('employee_cur is still open');
      ELSE
         DBMS_OUTPUT.put_line ('employee_cur is closed');
      END IF;
   END;

Nothing wrong with that, of course. Works just fine.

But there's a lot of repetition. I hate that. I like to normalize my code. And when the repetitive code is based on an IF statement, I immediately think of CASE - expressions:

   PROCEDURE show_cursor_status
   IS
   BEGIN
      DBMS_OUTPUT.put_line (
            'all_in_one_cur is '
         || CASE WHEN all_in_one_cur%ISOPEN THEN 'open' ELSE 'closed' END);

      DBMS_OUTPUT.put_line (
            'department_cur is '
         || CASE WHEN department_cur%ISOPEN THEN 'open' ELSE 'closed' END);

      DBMS_OUTPUT.put_line (
            'employee_cur is '
         || CASE WHEN employee_cur%ISOPEN THEN 'open' ELSE 'closed' END);
   END;

But, wait, still....there's more repetition: each of those CASE expressions. So I can use a nested function to encapsulate all of that, and I am left with:

   PROCEDURE show_cursor_status
   IS
      FUNCTION cursor_state (isopen_in IN BOOLEAN)
         RETURN VARCHAR2
      IS
      BEGIN
         RETURN CASE WHEN isopen_in THEN 'open' ELSE 'closed' END;
      END;
   BEGIN
      DBMS_OUTPUT.put_line (
         'all_in_one_cur is ' || cursor_state (all_in_one_cur%ISOPEN));

      DBMS_OUTPUT.put_line (
         'department_cur is ' || cursor_state (department_cur%ISOPEN));

      DBMS_OUTPUT.put_line (
         'employee_cur is ' || cursor_state (employee_cur%ISOPEN));
   END;

Ah....much better. No code repetition. Of course, in a subprogram this small, repetition is not too deadly a problem. Still, programs tend to get more complex over time, not simpler.

So assuming you (I) will be coming back to this code in the future, making sure that any particular piece of logic is implemented in just once place greatly reduces the cost and complexity of maintenance going forward, and also reduces the chance of introducing bugs.

Follow Up

I invited readers (via Twitter) to improve upon my code, and BluShadow came through with:

PROCEDURE show_cursor_status
IS
   PROCEDURE cursor_state (cur_name IN VARCHAR2, isopen_in IN BOOLEAN)
   IS
   BEGIN
      DBMS_OUTPUT.put_line (
            cur_name
         || ' is '
         || CASE WHEN isopen_in THEN 'open' ELSE 'closed' END);
   END;
BEGIN
   cursor_state ('all_in_one_cur', all_in_one_cur%ISOPEN);
   cursor_state ('department_cur', department_cur%ISOPEN);
   cursor_state ('employee_cur', employee_cur%ISOPEN);
END;

Comments

  1. Great to know that we can use CASE in dbms_output

    ReplyDelete
    Replies
    1. You bet!

      DBMS_OUTPUT.put_line accepts a string as its only argument. So you can pass to this built-in any expression that evaluates to (or can be implicitly converted to) a string.

      That certainly includes a CASE expression.

      Delete
  2. Still too much repetition... I'd go for:

    PROCEDURE show_cursor_status (str IN VARCHAR2)
    IS
    PROCEDURE cursor_state (cur_name IN VARCHAR2, isopen_in IN BOOLEAN)
    IS
    BEGIN
    DBMS_OUTPUT.PUT_LINE(cur_name||' is '|| CASE WHEN isopen_in THEN 'open' ELSE 'closed' END);
    END;
    BEGIN
    cursor_state('all_in_one_cur', all_in_one_cur%ISOPEN);
    cursor_state('department_cur', department_cur%ISOPEN);
    cursor_state('employee_cur', employee_cur%ISOPEN);
    END;

    ;)

    ReplyDelete
  3. I'm wondering why you went from:

    PROCEDURE show_cursor_status IS

    to:

    PROCEDURE show_cursor_status (str IN VARCHAR2) IS

    The added unused parameter will break any code that was using the original spec.

    ReplyDelete
  4. Thanks for pointing that out, David. I should have removed the str parameter. I pulled this code out of a quiz I was writing, and that was displaying the "context." Not relevant here. Fixing now.

    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

My two favorite APEX 5 features: Regional Display Selector and Cards

We (the over-sized development team for the PL/SQL Challenge - myself and my son, Eli) have been busy creating a new website on top of the PLCH platform (tables and packages): The Oracle Dev Gym! In a few short months (and just a part time involvement by yours truly), we have leveraged Oracle Application Express 5 to create what I think is an elegant, easy-to-use site that our users will absolutely love.  We plan to initially make the Dev Gym available only for current users of PL/SQL Challenge, so we can get feedback from our loyal user base. We will make the necessary adjustments and then offer it for general availability later this year. Anyway, more on that as the date approaches (the date being June 27, the APEX Open Mic Night at Kscope16 , where I will present it to a packed room of APEX experts). What I want to talk about today are two features of APEX that are making me so happy these days: Regional Display Selector and Cards. Regional Display Sel