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

Get rid of mutating table trigger errors with the compound trigger

When something mutates, it is changing. Something that is changing is hard to analyze and to quantify. A mutating table error (ORA-04091) occurs when a row-level trigger tries to examine or change a table that is already undergoing change (via an INSERT, UPDATE, or DELETE statement). In particular, this error occurs when a row-level trigger attempts to read or write the table from which the trigger was fired. Fortunately, the same restriction does not apply in statement-level triggers.

In this post, I demonstrate the kind of scenario that will result in an ORA-04091 errors. I then show the "traditional" solution, using a collection defined in a package. Then I demonstrate how to use the compound trigger, added in Oracle Database 11g Release1,  to solve the problem much more simply.

All the code shown in this example may be found in this LiveSQL script.

How to Get a Mutating Table Error

I need to implement this rule on my employees table:
Your new salary cannot be more than 25x th…

Table Functions, Part 1: Introduction and Exploration

August 2018 update: please do feel encourage to read this and my other posts on table functions, but you will learn much more about table functions by taking my Get Started with PL/SQL Table Functions class at the Oracle Dev Gym. Videos, tutorials and quizzes - then print a certificate when you are done!


Table functions - functions that can be called in the FROM clause of a query from inside the TABLE operator - are fascinating and incredibly helpful constructs.

So I've decided to write a series of blog posts on them: how to build them, how to use them, issues you might run into.

Of course, I am not the first to do so. I encourage to check out the documentation, as well as excellent posts from Adrian Billington (search for "table functions") and Tim Hall. Adrian and Tim mostly focus on pipelined table functions, a specialized variant of table functions designed to improve performance and reduce PGA consumption. I will take a look at pipelined table functions in the latte…

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 perspective…