I am trying to understand complier optimizations in plsql in depth. Theoretically, default optimisation level PLSQL_OPTIMIZE_LEVEL
is set to 2. To get better performance, we can set it to 3. To explain this to myself, I am using an example wherein a procedure is calling another procedure, so that the optimisation feature of level 3 (inline procedure) can be used.
Here is the first procedure:
create or replace procedure p1 is n number:=0; begin for i in 1..500000000 loop n:=n+1; end loop; end;
And here is the second one:
create or replace procedure CALL_PROC_ARITH IS BEGIN for i in 1..10 loop P1; end loop; END;
Here is the plsql_code_type
for both the procedures, which is INTERPRETED
.
So initially the optimisation level for both procedures is 2. And when I execute the procedure CALL_PROC_ARITH
, it takes about 05:00.866 minutes.
Later, I modify the optimisation level to 3 at session level. And when I execute the procedure CALL_PROC_ARITH
, it takes about 00:05:05.011 minutes which is an increase in 5 seconds.
Can someone please tell me why I see this deviation from the expected behaviour?
Will I get to see different results in case I use NATIVE compilation?
Note: I am running this from an IDE, and not directly from the SQLPlus CLI.
DB:Oracle 18c XE
Advertisement
Answer
You should use better sources to understand PLSQL_OPTIMIZE_LEVEL
, and you should make sure you’re testing the right thing the right way.
1. How does PLSQL_OPTIMIZE_LEVEL work?
The best way to learn about any parameter is with the Database Reference in the official documentation. The parameter PLSQL_OPTIMIZE_LEVEL
changes frequently, so make sure you reference the precise version. There’s a lot of unofficial, out-date information on the web, but here’s the relevant text for 18c:
0
Maintains the evaluation order and hence the pattern of side effects, exceptions, and package initializations of Oracle9i and earlier releases. Also removes the new semantic identity of BINARY_INTEGER and PLS_INTEGER and restores the earlier rules for the evaluation of integer expressions. Although code will run somewhat faster than it did in Oracle9i, use of level 0 will forfeit most of the performance gains of PL/SQL in Oracle Database 10g.
1
Applies a wide range of optimizations to PL/SQL programs including the elimination of unnecessary computations and exceptions, but generally does not move source code out of its original source order.
2
Applies a wide range of modern optimization techniques beyond those of level 1 including changes which may move source code relatively far from its original location.
3
Applies a wide range of optimization techniques beyond those of level 2, automatically including techniques not specifically requested.
That description makes it hard to tell when inlining will occur. It sounds like inlining might occur at level 1 and will likely occur at level 2. My tests below show a large inlining performance difference from 0 to 1, a very tiny difference from 1 to 2, and no difference from 2 to 3.
But a lot of the behavior is undocumented so it’s hard to tell which optimization will happen when.
2. Are you recompiling the code after setting the level?
Merely setting the session value is not enough, you must also recompile the procedures, like this:
alter session set plsql_optimize_level=3; alter procedure call_proc_arith compile; alter procedure p1 compile;
3. Are you really testing inlining?
Your procedures contain a lot of looping and a procedure call, but I think you have the numbers backwards. To test inlining, you must have the large loop calling the procedure, with the small loop doing the counting. You’ll never notice a compiler difference with only 10 procedure calls.
I used these procedures for my tests:
create or replace procedure p2 is n number:=0; begin for i in 1..5 loop n:=n+1; end loop; end; / create or replace procedure CALL_PROC_ARITH2 is begin for i in 1..10000000 loop p2; end loop; end; / --Check the PL/SQL optimize level for the objects. select name, plsql_optimize_level, plsql_code_type from all_plsql_object_settings where owner = user and name like 'CALL_PROC%' or name like 'P_';
4. Is your testing method robust enough?
Your tests should try to compensate for other activity consuming the CPU. Run multiple small tests in alternating order, throw out the high and low values, and compare the averages. A five second difference from running a five minute test twice is not significant.
I used the below PL/SQL blocks to test run times. (You can build a PL/SQL program to run the blocks in random order and record the times. I did that part manually.)Level 3 and 2 run the same speed, level 1 is a tiny bit slower, and level 0 is significantly slower.
--Level 3: 3.331, 3.403, 3.419 alter session set plsql_optimize_level = 3; alter procedure call_proc_arith2 compile; alter procedure p2 compile; begin call_proc_arith2; end; / --Level 2: 3.383, 3.470, 3.444 alter session set plsql_optimize_level = 2; alter procedure call_proc_arith2 compile; alter procedure p2 compile; begin call_proc_arith2; end; / --Level 1: 3.867, 3.859, 3.873 alter session set plsql_optimize_level = 1; alter procedure call_proc_arith2 compile; alter procedure p2 compile; begin call_proc_arith2; end; / --Level 0: 6.286, 6.296, 6.315 alter session set plsql_optimize_level = 0; alter procedure call_proc_arith2 compile; alter procedure p2 compile; begin call_proc_arith2; end; /
5. Do you even care about PL/SQL optimizations?
In most real-world PL/SQL programs, inlining procedures will not make a meaningful difference. The best practice is to do as much heavy lifting as possible with SQL. But regardless of where your logic is, make sure that you are using a profiler and only tuning parts of the program that take a significant amount of time. Before tuning part of a PL/SQL program, you should have some hard numbers, like “if I optimize line X the program could run up to Y% faster.”