Skip to main content

Does the PL/SQL compiler remove code that is used?

Yes. No. Sort of.

 It's (not all that) complicated.

This question hit my Twitter feed yesterday:
When you enable all warnings, have you ever seen a "PLW-06006-- uncalled procedure removed" (lots of them), when they surely are called?
Now that, I must admit, has to be a little bit concerning. You write code, you know it is going to, or should be, executed, and yet the PL/SQL compiler tells you it's been removed?

OK, OK, calm down. Everything is just fine.

Here's the explanation:
  • The optimizer performed an inlining optimization, so all the code for that procedure (or function) was moved to where it is invoked.
  • The "original" nested or private subprogram that you wrote (and, don't worry, is still and always will be in the source code of your program unit) is, truth be told, never going to be called. 
  • So then the compiler removed it (did not include it in the compiled code - which is not PL/SQL code any longer).
Let's take a look at some code, and what happens when we run it (you can see this for yourselves via my LiveSQL script):
ALTER SESSION SET plsql_optimize_level = 3
/

Statement processed

ALTER SESSION SET plsql_warnings='enable:all'
/

Statement processed

CREATE OR REPLACE PROCEDURE show_inlining
   AUTHID DEFINER
IS
   FUNCTION f1 (p NUMBER)
      RETURN PLS_INTEGER
   IS
   BEGIN
      RETURN p * 10;
   END;

   FUNCTION f2 (p BOOLEAN)
      RETURN PLS_INTEGER
   IS
   BEGIN
      RETURN CASE WHEN p THEN 10 ELSE 100 END;
   END;

   FUNCTION f3 (p PLS_INTEGER)
      RETURN PLS_INTEGER
   IS
   BEGIN
      RETURN p * 10;
   END;
BEGIN
   DBMS_OUTPUT.put_line ('f1 called: ' || f1 (1));

   PRAGMA INLINE (f2, 'YES');
   DBMS_OUTPUT.put_line ('f2 called: ' || TO_CHAR (f2 (TRUE) + f2 (FALSE)));

   PRAGMA INLINE (f3, 'NO');
   DBMS_OUTPUT.put_line ('f3 called: ' || f3 (55));
END;
/

Warning: PROCEDURE SHOW_INLINING
Warning: PROCEDURE SHOW_INLINING 
Line/Col: 4/4 PLW-06027: procedure "F1" is removed after inlining 
Line/Col: 10/4 PLW-06027: procedure "F2" is removed after inlining 
Line/Col: 22/4 PLW-06005: inlining of call of procedure 'F1' was done 
Line/Col: 25/4 PLW-06005: inlining of call of procedure 'F2' was done 
Line/Col: 25/4 PLW-06004: inlining of call of procedure 'F2' requested 
Line/Col: 25/4 PLW-06005: inlining of call of procedure 'F2' was done 
Line/Col: 25/52 PLW-06004: inlining of call of procedure 'F2' requested 
Line/Col: 28/4 PLW-06008: call of procedure 'F3' will not be inlined

BEGIN
   show_inlining;
END;
/

f1 called: 10
f2 called: 110
f3 called: 550
Please note: all the functions (f1 - f3) were executed!

As you can see, the warnings feedback ("PLW" stands for PL/SQL Warning) tells the story: procedures are removed after inlining.

Though I suppose we could be a little more explicit - and reassuring - and say:
PLW-06027: procedure "F1" is removed after inlining....
but just from the compiled code, not the source code of your program unit!

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