Skip to main content

Blogging about 11g : Function Result Cache

From the 11g New Features Guide:
"New in 11.1 is the ability to mark a PL/SQL function to indicate that its result should be cached to allow lookup, rather than recalculation, on the next access when the same parameter values are called. This function result cache saves significant space and time. Oracle does this transparently using the input actuals as the lookup key. The cache is system-wide so that all distinct sessions invoking the function benefits. If the result for a given set of actuals changes, you can use constructs to invalidate the cache entry so that it will be properly recalculated on the next access. This feature is especially useful when the function returns a value that is calculated from data selected from schema-level tables. For such uses, the invalidation constructs are simple and declarative.
Concurrent, multi-user applications that use this feature experience better response times. Applications that implement a session-private scheme consume significantly less memory by using this feature and, therefore, experience improved scalability."


Let's see if this statement is true:
First create a (simple) function with the 'result_cache' construct but without the 'relies_on' construct:

SQL> CREATE OR REPLACE FUNCTION CALC_SALARY_WITH_COMM
2 (p_emp_id EMPLOYEES.EMPLOYEE_ID%TYPE)
3 RETURN NUMBER
4 result_cache
5 --relies_on (employees)
6 is
7   l_salary employees.salary%type;
8   l_comm number;
9   l_result number;
10 BEGIN
11   select salary
12   ,      1 + nvl(commission_pct,0)
13   into   l_salary
14   ,      l_comm
15   from   employees
16   where  employee_id = p_emp_id;
17   l_result := l_salary * l_comm;
18   return l_result;
19 exception
20   when no_data_found
21   then
22     RETURN 0;
23 END;
24 /

Call the function and cache the results of the calculation

SQL> select
2    ,      last_name
3    ,      salary
4    ,      commission_pct
5    ,      calc_salary_with_comm( employee_id ) total
6 from employees
7 where last_name = 'King'
8 /

LAST_NAME SALARY COMMISSION_PCT TOTAL
--------- -----  -------------- ----------
King      10000                 10000
King      24000                 24000

Change the values used in the calculation

SQL> update employees
2 set commission_pct = 0.99
3 where last_name = 'King'
4 /

Issue the select statement again and check that the results of the calculations are not changed! (this is due to the lack of the "RELIES_ON" clause)

LAST_NAME SALARY COMMISSION_PCT TOTAL
--------- -----  -------------- ----------
King      10000             .99 10000
King      24000             .99 24000

When you create another session and issue the select statement in this session you'll see that the results are still from the cache...(because they're still 'wrong').

Reset the values used in the calculation

SQL> update employees
2 set commission_pct = null
3 where last_name = 'King'
4 /

Now recreate the function with the "RELIES_ON" clause

SQL> CREATE OR REPLACE FUNCTION CALC_SALARY_WITH_COMM
2 (p_emp_id EMPLOYEES.EMPLOYEE_ID%TYPE)
3 RETURN NUMBER
4 result_cache
5 relies_on (employees)
6 is
7   l_salary employees.salary%type;
8   l_comm number;
9   l_result number;
10 BEGIN
11   select salary
12   ,      1 + nvl(commission_pct,0)
13   into   l_salary
14   ,      l_comm
15   from   employees
16   where  employee_id = p_emp_id;
17   l_result := l_salary * l_comm;
18   return l_result;
19 exception
20   when no_data_found
21   then
22     RETURN 0;
23 END;
24 /

Issue the select statement and that will cache the results of the calculation
Change the values used in the calculation

SQL> update employees
2 set commission_pct = 0.99
3 where last_name = 'King'
4 /

Issue the select statement and check that the results of the calculations are changed now

LAST_NAME SALARY COMMISSION_PCT TOTAL
--------- -----  -------------- ----------
King      10000             .99 19900
King      24000             .99 47760

Reset the values used in the calculation

SQL> update employees
2 set commission_pct = null
3 where last_name = 'King'
4 /

Now do a little performance test

Create a similar function that doesn't cache

SQL> CREATE OR REPLACE FUNCTION CALC_SALARY_WITH_COMM_NC
2 (p_emp_id EMPLOYEES.EMPLOYEE_ID%TYPE)
3 RETURN NUMBER
4 -- result_cache
5 -- relies_on (employees)
6 is
7   l_salary employees.salary%type;
8   l_comm number;
9   l_result number;
10 BEGIN
11   select salary
12   ,      1 + nvl(commission_pct,0)
13   into   l_salary
14   ,      l_comm
15   from   employees
16   where  employee_id = p_emp_id;
17   l_result := l_salary * l_comm;
18   return l_result;
19 exception
20   when no_data_found
21   then
22     RETURN 0;
23 END;
24 /

First call the function 100.000 times without caching

SQL> declare
2 result number;
3 begin
4 for i in 1..100000 loop
5 select calc_salary_with_comm_nc( employee_id ) total
6 into result
7 from employees
8 where employee_id = 100;
9 end loop;
10 end;
11 /

PL/SQL procedure successfully completed.

Elapsed: 00:00:16.80

Next call the function 100.000 times with caching

SQL> declare
2 result number;
3 begin
4 for i in 1..100000 loop
5 select calc_salary_with_comm( employee_id ) total
6 into result
7 from employees
8 where employee_id = 100;
9 end loop;
10 end;
11 /

PL/SQL procedure successfully completed.

Elapsed: 00:00:09.78

In this example the result is that the cached version is 40% faster....

The cached results are visible in V_$RESULT_CACHE_OBJECTS. If the RELIES_ON clause is used the cached result becomes "Invalid" when (whatever which) data of the table is changed. Why these "Invalid" cached results are still available is a mystery to me (why aren't they deleted?).

It seems that using this feature you can enhance the performance (when used wisely...).

As specified, this feature is (very) usefull when a function returns a kind of (complex) calculation using non-frequently changed table(s) - or no tables at all.
Untill now a developer usually caches these kinds of values (like parameter values) in a package variable (or array), but that's a per session solution. Using this feature the cached results are available in every session! The risk is ofcourse that the developer "forgets" using the RELIES_ON clause (it is optional!).
1 comment

Popular posts from this blog

Showing a success message after closing a modal dialog

APEX 5 comes with Modal Dialogs out of the box. Very neat. Especially for adding and changing data. And to minimise the number of time a user has to click, it could be useful to add a "Close Dialog" process after the actual data processing. When the data processing fails, the Dialog stays on top showing the error. When data processing runs fine, the Dialog is closed ... without any confirmation. And this might be scary for a shaky user.

So how can we provide the user some feedback? On Page 4 of the Sample Dialog Application you can see one solution: up on a Dialog Closed Event on the parent page it does a redirect to refresh the parent page appending the success message of the "Close Dialog" process. This has two drawbacks. First, it probably refreshes more than necessary. And second, if you're using multiple layers of dialogs (dialogs that open other dialogs) the message appears in the "parent dialog".
As an alternative you could follow these steps: 1…

A review of APEX World 2017 - Day 1

Last week the SS Rotterdam was the beautiful location of the largest gathering of APEX Developers worldwide. With around 380 (!) attendees a new high was set. And they came from all over the world : I spotted people from The Netherlands, Belgium, Switzerland, Austria, Croatia, Germany, Denmark, Norway, UK, Ireland and the USA. And I even might have missed one or two ….

The event started with a presentation by the “father of APEX”, Mike Hichwa, talking about "Oracle APEX Past, Present and Future”. Of course everyone is curious what the APEX future might bring: Friendly URL’s, automated testing, more JSON, concurrent APEX versions, third party Oauth 2 authentication (think Facebook, Google), APEX app diff and more, a lot more, REST capabilities. And now we have to wait for APEX 5.2 … and that might take a while! 
After this keynote, the conference split up in three tracks. After the coffee break I returned to to big theatre where Geertjan Wielenga talked about "Finally Javas…

Push changed rows to an Interactive Grid

For pushing changes from the database to the end user, the regular solution is using websockets. A change in a record is detected - using a trigger or using the CQN (Change Query Notification) feature - and a notification is send to a websocket server. That websocket server broadcasts the notification over a channel to all browsers that are tuned in to that websocket channel. Then the browser reacts to that notification, usually showing an alert or refreshing a report. This trick is described on multiple sites, just Google for "oracle apex websockets" or similar.

So back in the old days, we used that notification in the browser to refresh the (interactive) report. But along comes the Interactive Grid (IG). While he full-refresh mechanism still works for IG, an IG has also the option to refresh just one row.  So wouldn't it be awesome that just the changed row(s) get refreshed upon a change in the database, instead of the whole report? Can we do it ... yes we can!
First i…