Caution when using PL/SQL functions in a SQL statement

Be cautious if you use PL/SQL functions/packages in your SQL statements, especially in the Where-Clause!

Why?

Because the function is probably called more often than you think it is! If you don’t want to read the hole article, scroll down and check the APEX impact.

An example

Let’s create the following simple function.

CREATE OR REPLACE FUNCTION getValue
  ( pValue IN NUMBER
  )
RETURN NUMBER
IS
BEGIN
  DBMS_Output.put_line
    ( 'called getValue with '||pValue||' at '||
      TO_CHAR(SYSDATE, 'HH24:MI:SS')
    );
  RETURN pValue;
END getValue;

And now look at the following SQL Statement where we call our new function with a constant value.

SELECT COUNT(*)
  FROM EMPLOYEES
 WHERE SALARY = getValue(1)
;

How often do you think is the function called?

  • One time because it always uses the same value as parameter?
  • For each row which is checked by the query engine?
  • Some number between one time and for all rows?

Check the DBMS_Output.

If you have bet your money on For each row which is checked by the query engine, then you are the winner! It’s called 107 times! As often as we have rows in the table.

If we change the query to

SELECT COUNT(*)
  FROM EMPLOYEES
 WHERE EMPLOYEE_ID > getValue(1)
;

How often to you think it is called? You have the same choice as before.

Check the DBMS_Output.

It’s just called one time! What is the difference? In our second example the optimizer is using the EMP_EMP_ID_PK index and in that case as Tom Kyte explained me

The optimizer gets the start/stop range (the function might be called twice actually) and then it range scans with the constants.

So what’s the deal all about it?

Keep in mind the performance issue when you have a function which is selecting against other tables and you use such a function in a where-clause, where 1.000’s of records are processed!

Possible solutions?

You can change the query in the following way. The optimizer then knows that is ok when he executes the query just one time. So called scalar subquery caching, which works with all DB versions. Checkout AskTom about that term.

SELECT COUNT(*)
  FROM EMPLOYEES
 WHERE SALARY = (SELECT getValue(1) FROM DUAL)
;

Or you take a look at the DETERMINISTIC clause which can specified when creating a function or a package functions. What does it do? It’s a hint for the optimizer to indicate that the function returns the same result value whenever it is called with the same values for its arguments. But, as noted by Tom Kyte

10gr2 supports deterministic as an optimization in SQL for the first time. Prior to 10gr2 – deterministic was all about function based indexes only – the SQL engine ignored it.

So only if you have a 10.2.x database, using DETERMINISTIC will give you a speed up of your query. Use the above solution instead.

But let’s change our function and see what we get now.

CREATE OR REPLACE FUNCTION getValue
  ( pValue IN NUMBER
  )
RETURN NUMBER DETERMINISTIC
IS
BEGIN
  DBMS_Output.put_line
    ( 'called getValue with '||pValue||' at '||
      TO_CHAR(SYSDATE, 'HH24:MI:SS')
    );
  RETURN pValue;
END getValue;

Run the first query again and you will see that the function is called just once!
Try the following SQL statement.

SELECT COUNT(*)
  FROM EMPLOYEES
 WHERE SALARY = getValue(SALARY)
;

How often do you think it is called? It’s just called as often as there are different salaries in the table. With the old version of the function is called for each row again.

I know that the Oracle documentation about DETERMINISTIC says

Do not specify this clause to define a function that uses package variables or that accesses the database in any way that might affect the return result of the function.

Which I think is basically to see in relation to the function based index for which this “hint” has been introduced. From my observation, if you have such a function call in several SQL statements which are called after each other (eg in a anonymous pl/sql block), the function is executed again for each SQL statement. It’s just a hint for the optimizer during execution of the current statement.

DON’T USE DETERMINISTIC if your function is changing some global variables (eg increase a counter) or doing DML and you expect that the function is called for each row!

And how is that all related to APEX?

Are you using the V or NV function in your SQL statements? In APEX 2.0 the V function isn’t wrapped (in 2.2 it is) and I don’t see that the DETERMINISTIC is used in the code… It’s just memory processing they do in there, but if you call it for 1.000’s of records…

Always use bind variables instead! Only use the V function in your packages, but never use them in your report SQL statements.

I have done a posting on OTN about speeding up the V function. Stay tuned.

UPDATE: See my posting Drop in replacement for V and NV function which contains a wrapper for the existing functions.

8 thoughts on “Caution when using PL/SQL functions in a SQL statement

  1. Hi Damir,

    for a table with just a few rows it’s probably no problem, but there are always tables which have more rows in them and developers tend to use “design patterns” they have already used in the past. And in that case you have bad performance.

    I think in such a case it’s better to already come up with a more performant solution, also for the small tables. To have a better “design pattern” for the future, where you don’t have to care anymore.

    I think using the APEX feature “Application Attributes/Edit Security Attributes/Virtual Private Database” is a much better approach. Setting the context with DBMS_Session.set_context and using SYS_CONTEXT in the view definition is much better. I can not prove it, but I would assume that the SYS_CONTEXT is defined deterministic and just called once by the optimizer/query engine.

  2. This is well-known and obvious for SQL-tuners thing.

    Just ALWAYS test all SQL and PL/SQL code for real data volumes before production and this ‘problem’ solves natively.

    Anyway, when use TurDuckEn code of ApEx, PL/SQL is most uses language.

    So, all trivial:

    declare
    v_x number;
    v_res varchar2;
    bedin
    v_x := f(p_x);
    select abc
    into v_res
    from t_table
    where v_x between col1 and col2;
    end;

    works more better than

    declare
    v_res varchar2;
    bedin
    select abc
    into v_res
    from t_table
    where f(p_x) between col1 and col2;
    end;

    Depending of table size – the difference in speed for both blocks can consists from 30 to 300 times.

    No matter how good table indexes.

    In second example the f() function calls every time in RANGE SCAN with index for query.

    As I said – trivial.

    Patrick, I think, Your target audithory not so stupid. :)

  3. Yuri,

    I’m not so sure if it was well-known by the average developer. And if you know something you always think that’s trivial and why haven’t I known this before. :-)

    Regards
    Patrick

  4. Patrick,

    your absolutely right. But my 12 years DBA’s background and experience tells me this issue is not an Oracle – it’s brain issue ;) for developers. Just explain plan for every query incorporated into ApEx and a bit think – and much PL/SQL-SQL issues will be obvious.

    I’ve checked execution plan for EVERY query I wrote for ApEx applications. Every query is testing on real volumes of data. Every front-end query is tuning for response time. Always.

    Well-tuned queries = quick responses Web-applications.

    This is the most important for hybrid PL/SQL-SQL code – quality and performance of all code.

    “Divide et impera” – a good principe not only in politics, but also in programming.

    In my example – separated computation of function wich ALWAYS must be determimistic ALWAYS gives incredible performance impact.

  5. Hi I want to learn about ORACLE and to be a software developer in near future right now in studying ORACLE, but my professor in ORACLE is a very low to taech and actually my co-classmate hey said she is not a good professor, so if there is someone to teach me a good samaritan, Im willing and eager to learn ORACLE software and not also a developer, I want a beyond a developer. Im Accounting graduate, not working a job seeker, and willing to learn more about IT. Thanks.

  6. Hi,
    I am new to Oracle Appex,
    i would like to know validation of any String with Regualr Expression option [a-z,A-Z ]+. Only this character alows, When i m trying to use above pattern.its not working .
    Can u tell me the ways to do validation
    1) Using SQL expression, i can validate or not???
    2) Using pl/SQL expression, i can validate or not???
    3) Regular Expression, i can validate or not or not???

    Test Case ::
    1) efraer345 should be failed
    2)2342er should be failed
    3) #$%#$%sdfas34 should be failed
    4)rahul bhandari should be pass
    5) dfsd_` should be failed

Comments are closed.