Skip to main content

How to make sure your code FAILS to compile

Huh, what?

Make sure my code fails to compile?

Why would I want to do that.

Well, suppose that you had a compute-intensive procedure that ran every hour and benefited greatly from full PL/SQL compiler optimization (level set to 3, to take advantage of subprogram inlining and everything else it does).

Next, suppose that somehow as the procedure (newly enhanced, fully tested) was being deployed to production, the optimization level was mistakenly set to 0 or 1. This would cause severe performance problems.

So in that case, wouldn't it be nice if you could build a "circuit breaker" into that procedure so that the compiler says "No go" even if the code itself compiles just fine?

I think it would be nice - and you can accomplish precisely that with the error directive of the conditional compilation feature of PL/SQL.

First, here's the code that demonstrates precisely the scenario outlined above.
CREATE OR REPLACE PROCEDURE compute_intensive
AUTHID DEFINER
IS
BEGIN
   $IF $$plsql_optimize_level < 3
   $THEN
      $ERROR 'compute_intensive must be compiled with maximum optimization!' $END
   $END
   
   /* All the intensive code here! */
   NULL;
END compute_intensive;
I check the system-defined inquiry directive, $$plsql_optimize_level, to see what the current optimization level is. If less than 3, the PL/SQL compiler encounters the $error directive.

At this point, the compiler rejects the procedure with this error:
PLS-00179: $ERROR: compute_intensive must be compiled with maximum optimization!
Notice that the string after the $error directive becomes the compilation error message the developer will see.

You can try this yourself with my LiveSQL script.

You might also use $error to mark "not done" parts in your code. It's a lot more effective than a comment like this:
/*TODO Finish section */
and it guarantees that partially written code will never make it into production, no matter how distracted you are. Here's an example. On line 24, I've got to deal with my ELSE condition, but no time right now! So I quick1y drop in a $error snippet I've created, and add the appropriate message. Notice that I include two other system defined directives, $$plsql_unit and $$plsql_line.
FUNCTION list_to_collection (
   string_in      IN   VARCHAR2
 , delimiter_in   IN   VARCHAR2 DEFAULT ','
)
   RETURN DBMS_SQL.varchar2a
IS
   l_next_location PLS_INTEGER := 1;
   l_start_location PLS_INTEGER := 1;
   l_return DBMS_SQL.varchar2a;
BEGIN
   IF string_in IS NOT NULL
   THEN
      WHILE ( l_next_location > 0 )
      LOOP
         -- Find the next delimiter
         l_next_location := 
            NVL (INSTR ( string_in, delimiter_in, l_start_location ), 0);

         IF l_next_location = 0
         THEN
            -- No more delimiters, go to end of string
            l_return ( l_return.COUNT + 1 ) :=
                 SUBSTR ( string_in, l_start_location );
         ELSE
            $ERROR
            'list_to_collection INCOMPLETE!
             Finish extraction of next item from list.
             Go to ' || $$PLSQL_UNIT || ' at line ' || $$PLSQL_LINE
            $END
         END IF;
         l_start_location := l_next_location + 1;
      END LOOP;
   END IF;
   RETURN l_return;   
END list_to_collection;
When I try to compile the code, I see this error:
PLS-00179: $ERROR: list_to_collection INCOMPLETE! 
             Finish extraction of next item from list. 
             Go to LIST_TO_COLLECTION at line 28
Those are two ideas I've come up with for $error. I bet you will come up with more of your own. When you do, please let us know by adding a comment to this post!

Conditional Compilation Series
1. An introduction to conditional compilation
2. Viewing conditionally compiled code: what will be run?
3. Writing code to support multiple versions of Oracle Database
4. Setting and using your own conditional compilation flags
5. How to make sure your code FAILS to compile

Comments

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 work, revamping algorithms, ensuring correctness, you know the score. Then my eyes snagge

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,

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