Result Cache Functions
I finally got around to cleaning up old contact me messages. One of the messages raises a question about RESULT_CACHE functions. The writer wanted an example implementing both a standalone schema and package RESULT_CACHE function.
The question references a note from the Oracle Database 11g PL/SQL Programming book (on page 322). More or less, that note points out that at the time of writing a RESULT_CACHE function worked as a standalone function but failed inside a package. When you tried it, you raised the following error message:
PLS-00999: Implementation Restriction (may be temporary) |
It’s no longer true in Oracle 11gR2, but it was true in Oracle 11gR1. I actually mentioned in a blog entry 4 years ago.
You can implement a schema RESULT_CACHE function like this:
1 2 3 4 5 6 7 8 | CREATE OR REPLACE FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE IS BEGIN RETURN pv_first_name || ' ' || pv_last_name; END full_name; / |
You would call it like this from a query:
SELECT full_name(c.first_name, c.last_name) FROM contact c; |
You can declare a published package RESULT_CACHE function like this:
1 2 3 4 5 6 7 | CREATE OR REPLACE PACKAGE cached_function IS FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE; END cached_function; / |
You would implement the function in a package body like this:
1 2 3 4 5 6 7 8 9 10 | CREATE OR REPLACE PACKAGE BODY cached_function IS FUNCTION full_name ( pv_first_name VARCHAR2 , pv_last_name VARCHAR2 ) RETURN VARCHAR2 RESULT_CACHE IS BEGIN RETURN pv_first_name || ' ' || pv_last_name; END full_name; END cached_function; / |
You would call the package function like this from a query:
SELECT cached_function.full_name(c.first_name, c.last_name) FROM contact c; |
I hope this answers the question.