Skip to main content

Don't Want to Remember No Stinking Error Codes

Programmers need to keep lots of information in their heads: about the language(s) with which they are writing code, the data model of their application, requirements, etc. So they tend to not remember (and even forget rather quickly) information they are pretty sure is not in their critical path.

I was reminded of this very forcefully at a two day course I gave in the Netherlands a few years ago. On the first day, I talked about FORALL and SAVE EXCEPTIONS, and how Oracle would raise ORA-24381 if at least one statement failed in the FORALL's execution.

Then at the end of the second day, when I discussed maintainability, I again talked about ORA-24381 (for reasons that will become clear below). And then, then it was time for the end-of-course ten-part quiz, with reputation and prizes on the line.

Lo and behold, when the dust settled, we had a tie for first place. So then it was time for a sudden death playoff. Whoever gave me the right answer first, wins.

I showed "-24381" on the screen and asked: "With what feature of PL/SQL is this number associated?"

Neither of the expert finalists had an answer and, amazingly, no one else in the class of 40 did, either.

It was very clear to me at that point that these developers....

Don't Want to Remember No Stinking Error Codes

OK, fine. It's a lot better to remember and work with meaningful names, than obscure numbers, right? As in:

DECLARE
   l_numbers DBMS_SQL.NUMBER_TABLE;
BEGIN
   DBMS_OUTPUT.PUT_LINE (l_numbers (1));
EXCEPTION
   WHEN NO_DATA_FOUND
   THEN
      DBMS_OUTPUT.PUT_LINE (
         'Tried to read an undefined index value!');
END;

And that's why Oracle gives names in the default STANDARD package to a whole bunch of the most commonly-occurring exceptions, such as NO_DATA_FOUND and VALUE_ERROR.

Sadly, no name was supplied for ORA-24381, so I guess that means we need to write code like this:

EXCEPTION
   WHEN OTHERS
   THEN
      IF SQLCODE = -24381
      THEN
         /* Traverse SQL%BULK_EXCEPTIONS for DML errors */
         ...
      ELSE
         RAISE;
      END IF;
END;

Really? Is that really what we have to do? I sure hope not, because this is (confession: slight exaggeration coming) horrifying, nervous breakdown-inducing code.

OK, maybe it's not that bad. But think about it: you write code today and it goes into production tomorrow. You move on to another project, and the code lives on. Five years later, a bug surfaces in that program, and someone who has never looked at your code opens it up and sees:

IF SQLCODE = -24381

and you know how it makes them feel? Ignorant, stupid, diminished. Afraid to touch your code, because you are/were obviously much smarter (or at least more expert with PL/SQL) than they. You obviously knew all about those weird error codes and they have no clue.

Now, if one of your objectives in writing code is trying to make other people feel bad and thereby pump yourself up, it's not that hard to do. Just write code that is hard to understand, maintain and debug. Leave out comments, hard-code magic values left and right. Then express astonishment when someone has trouble understanding what you wrote.

There are many words for programmers like this. One of them likely starts with an "a".

But if that's not the kind of programmer you want to be, if you'd rather be the sort who goes out of their way to make people feel welcome in their code, in which the intention and the algorithm are evident, and these "next generation" developers can make changes with some degree of confidence, then do like Oracle does:

Reference those obscure error codes by name.

But, wait, you are thinking: "Steven just said that Oracle did not define a name for ORA-24381."

Yes, that is so. But nothing is stopping you from doing that yourself!

Create a package to hold all of your named exceptions, and then do the same thing that you will find in STANDARD: use the EXCEPTION_INIT pragma to associate a named exception with a number:

CREATE OR REPLACE PACKAGE my_errors
IS
   forall_failure EXCEPTION;
   PRAGMA EXCEPTION_INIT (forall_failure, -24381);
END;
/

You can then reference those obscure error codes by name.

EXCEPTION
   WHEN my_errors.forall_failure
   THEN
      /* Traverse SQL%BULK_EXCEPTIONS for DML errors */
     ...
END;

No more hard-coding of error codes, no more expecting others to have the same relatively random, highly specialized knowledge you acquired.

In short, no showing off.


Comments

  1. Hello Steven,

    Maybe not exactly pertaining to this discussion only ...
    I just had a look at some SQL solutions posted up to now for the currently ongoing "Obfuscated SQL Contest" .

    You say:
    "Now, if one of your objectives in writing code is trying to make other people feel bad and thereby pump yourself up, it's not that hard to do.
    Just write code that is hard to understand, maintain and debug."

    To tell you the truth ?
    This is exactly how I felt when looking at some of those solutions ... and, for sure,
    "the winner" will be one of those ...

    I hope that you know what is the meaning of "K.I.S.S." ...
    when talking about software, of course ...

    Thanks a lot & Best Regards,
    Iudith

    ReplyDelete
  2. Never RAISE_APPLICATION_ERROR again... http://www.oraclenerd.com/2010/10/never-use-raiseapplicationerror-again.html

    ReplyDelete

Post a Comment

Popular posts from this blog

Running out of PGA memory with MULTISET ops? Watch out for DISTINCT!

A PL/SQL team inside Oracle made excellent use of nested tables and MULTISET operators in SQL, blending data in tables with procedurally-generated datasets (nested tables).  All was going well when they hit the dreaded: ORA-04030: out of process memory when trying to allocate 2032 bytes  They asked for my help.  The error occurred on this SELECT: SELECT  *    FROM header_tab trx    WHERE (generated_ntab1 SUBMULTISET OF trx.column_ntab)       AND ((trx.column_ntab MULTISET             EXCEPT DISTINCT generated_ntab2) IS EMPTY) The problem is clearly related to the use of those nested tables. Now, there was clearly sufficient PGA for the nested tables themselves. So the problem was in executing the MULTISET-related functionality. We talked for a bit about dropping the use of nested tables and instead doing everything in SQL, to avoid the PGA error. That would, however require lots of wo...

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, ...

PL/SQL 101: Three ways to get error message/stack in PL/SQL

The PL/SQL Challenge quiz for 10 September - 16 September 2016 explored the different ways you can obtain the error message / stack in PL/SQL. Note: an error stack is a sequence of multiple error messages that can occur when an exception is propagated and re-raised through several layers of nested blocks. The three ways are: SQLERRM - The original, traditional and (oddly enough) not currently recommended function to get the current error message. Not recommended because the next two options avoid a problem which you are unlikely  to run into: the error stack will be truncated at 512 bytes, and you might lose some error information. DBMS_UTILITY.FORMAT_ERROR_STACK - Returns the error message / stack, and will not truncate your string like SQLERRM will. UTL_CALL_STACK API - Added in Oracle Database 12c, the UTL_CALL_STACK package offers a comprehensive API into the execution call stack, the error stack and the error backtrace.  Note: check out this LiveSQL script if...