Watch out with function result cache based on data dictionary views

Result cache is a powerful tool to gain performance in PL/SQL.
There are many examples on the internet that proves this, e.g. these articles on All things Oracle:
Result Cache(1)
Result Cache(2)

But I’m not going to talk about performance.
This article is some kind of warning.

First I’ll show you how result cache works on a normal view.
I’ll create a table, a view on this table and a function that counts the rows in the view.

SQL> create table x (field1 varchar2(1), field2 number(1));

Table created.

SQL> create or replace view vie_x as select * from x;

View created.

SQL> CREATE OR REPLACE FUNCTION vie_x_rowcount(p_field1 IN VARCHAR2)
RETURN NUMBER RESULT_CACHE
IS
   l_return NUMBER;
BEGIN
   SELECT count(*)
     INTO l_return
     FROM vie_x
     WHERE field1 = p_field1;

   RETURN l_return;

END vie_x_rowcount;
/

Function created.

SQL> insert into x(field1, field2) values('x', 1);

1 row created.

SQL> commit;

Commit complete.

These are the statistics for the result cache, just to show you we’re starting without any caching.

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       0
Find Count		               0
Invalidation Count	           0

When we execute the function, the statistics show that there’s an entry created in the cache.

SQL> select vie_x_rowcount('x') from dual;

VIE_X_ROWCOUNT('X')
-------------------
		  1

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               0
Invalidation Count	           0

When we execute the same code again, we’ll get the same result and the statistics show us that the result is found in the cache.
Good job Oracle!

SQL> select vie_x_rowcount('x') from dual;

VIE_X_ROWCOUNT('X')
-------------------
		  1

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               1
Invalidation Count	           0

Let’s insert a new row in the table.
This time the statistics show us that the cache is “invalidated”, meaning the function has to be executed again to return the correct value.

SQL> insert into x values('x', 2);

1 row created.

SQL> commit;

Commit complete.

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               1
Invalidation Count	           1

And the expected result…

SQL> select vie_x_rowcount('x') from dual;

VIE_X_ROWCOUNT('X')
-------------------
		  2

The Oracle database has its own data dictionary, a set of tables where it stores all information about the database and what’s in it.
Data of these tables are available through views, data dictionary views.
In the following example I’ll use the data dictionary view that holds the information on columns.
I created a function that returns the number of columns for a certain table.

SQL> CREATE OR REPLACE FUNCTION number_of_columns(p_table_name VARCHAR2)
RETURN NUMBER RESULT_CACHE
IS

   l_return NUMBER;

BEGIN

   SELECT count(*)
     INTO l_return
     FROM user_tab_columns
    WHERE table_name = p_table_name;

   RETURN l_return;

END number_of_columns;
/

Function created.

To make sure we’ll start with a clean cache, I’ll flush it using the dbms_result_cache.flush procedure.

SQL> execute dbms_result_cache.flush

PL/SQL procedure successfully completed.

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       0
Find Count		               0
Invalidation Count	           0

When we execute the function, we’ll get the expected result: the function is executed and a cache entry is created.

SQL> select number_of_columns('X') from dual;

NUMBER_OF_COLUMNS('X')
----------------------
		     2

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               0
Invalidation Count	           0

We can execute it again and see that the return value is retrieved from the cache.

SQL> select number_of_columns('X') from dual;

NUMBER_OF_COLUMNS('X')
----------------------
		     2

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               1
Invalidation Count	           0

Let’s add a column to the table.
This should add a new row in a data dictionary table and thus in the data dictionary view we use in our function.

SQL> alter table x add (field3 date);

Table altered.

SQL> desc x
 Name					   Null?    Type
 ------------------------- -------- ----------------------------
 FIELD1 					        VARCHAR2(1)
 FIELD2 					        NUMBER(1)
 FIELD3 					        DATE

Now execute the function again.
And the result is…

SQL> select number_of_columns('X') from dual;

NUMBER_OF_COLUMNS('X')
----------------------
		     2

Not what we expected!
When we take a look at the result cache statistics, it shows that the cache wasn’t invalidated and the result was retrieved from the result cache.

SQL> select name, value from v$result_cache_statistics where name in ('Create Count Success', 'Find Count', 'Invalidation Count');

NAME			               VALUE
------------------------------ ------------------------------
Create Count Success	       1
Find Count		               2
Invalidation Count	           0

When we flush the cash and execute the function again, we’ll get the correct result cache.

SQL> execute dbms_result_cache.flush

PL/SQL procedure successfully completed.

SQL> select number_of_columns('X') from dual;

NUMBER_OF_COLUMNS('X')
----------------------
		     3

So, it seems that the result cache isn’t invalidated on data dictionary tables.
And indeed this is what I found in the Oracle documentation:

You cannot cache results when the following objects or functions are in a query:

  • Temporary tables and tables in the SYS or SYSTEM schemas

All things Oracle

There’s a new Oracle source available:  All Things Oracle.

The aim of All Things Oracle is to provide a gateway to the wealth of information and material available for Oracle developers and DBAs.
The site brings articles and other resources of Oracle experts.
Just to name a few:

All very experienced experts that will bring interesting articles!

I will also contribute to this site.
My specialities are SQL, PL/SQL, Forms and Forms Modernization, so expect articles on these topics in the near future on All Things Oracle.

PL/SQL Challenge first anniversary

One year ago Steven Feuerstein launched a competition called “The Pl/SQL Challenge“.
The idea was to let Oracle PL/SQL developers test their knowledge, learn and win prices by taking a daily quiz.

The format seems to be a success: every day more than 1000 PL/SQL developers test their knowledge about the language, in total more than 5800 users from 119 countries… a worldwide success!

But it does not stop with doing a quiz, a lot of questions(and answers) are discussed on the blog.
And those discussions can also lead to something, like an enhancement request for the PL/SQL language  by Bryn Llewellyn(PL/SQL Product Manager at Oracle).

Steven did a great job with the PL/SQL Challenge and it seems like it keeps on rolling: version 2 of the website is coming up with even more challenges for SQL and APEX.

To Steven and his team of reviewers and developers: thanks for the nice quizzes and keep up te great work!
To all players: have fun and good luck!

 

My quiz on the PL/SQL Challenge

On friday my quiz was on the PL/SQL Challenge.

Topic: “Guidelines for Designing Triggers: Avoid Non-Transactional Logic in DML Triggers”

Yes, about “statement restart” :-)
My idea about the quiz was “making developers aware of the Oracle behaviour”.
And I hope a lot of PL/SQL developers learned from it.

It wasn’t easy to come up with the question, the way of asking, the correct words, the answers…
But after a lot of mailing between Steven and the reviewers we finally had a quiz.

A lot people had it wrong, but I hope they don’t mind and are now aware of statement restart.

For more information and discussion about the quiz: PL/SQL Challenge blog

Statement restart

Today I explained the “statement restart” problem to a colleague.
Every database developer has to know about this one…

Short: Any statement can be restarted!
This means that when you do one update statement, oracle CAN restart the statement.
Every code in a trigger can be executed multiple times, so watch out with package variables and autonomous transactions in triggers.

Some code to test it:

CREATE TABLE test_trigger(val NUMBER)
/

CREATE OR REPLACE PACKAGE global_var
IS
g_val NUMBER;
END global_var;
/

CREATE OR REPLACE TRIGGER test_trig
BEFORE UPDATE
ON TEST_TRIGGER
REFERENCING NEW AS NEW OLD AS OLD
FOR EACH ROW
BEGIN
global_var.g_val := global_var.g_val + 1;
END ;
/

BEGIN
global_var.g_val := 0;
END;
/

INSERT
INTO test_trigger
( val
)
VALUES
( 0
)
/

DECLARE
l_val NUMBER;
BEGIN
SELECT val
INTO l_val
FROM test_trigger;

dbms_output.put_line(‘value in package global variable:’||global_var.g_val);
dbms_output.put_line(‘value in table:’||l_val);
END;
/

BEGIN
FOR i IN 1..100000
LOOP
UPDATE test_trigger
SET val = val +1;
END LOOP;
END;
/

DECLARE
l_val NUMBER;
BEGIN
SELECT val
INTO l_val
FROM test_trigger;

dbms_output.put_line(‘value in package global variable:’||global_var.g_val);
dbms_output.put_line(‘value in table:’||l_val);
END;
/

What’s the value of your global variable?

Or like Tom Kyte says: “Triggers or evil!”
More on this topic by Tom Kyte: That old restart problem again