Search the Reference Library pages:  

Oracle DBMS_RESULT_CACHE

Version 11.1
 
General Information
Note Client Side SQLNET.ORA client cache parameters are optional and they over-ride server settings. The OCI_RESULT_CACHE_MAX_SIZE must be set in bytes and must be at least 32768. For 2M set it to 2048000.

OCI_RESULT_CACHE_MAX_SIZE = 2048000
OCI_RESULT_CACHE_MAX_RSET_SIZE = 1024000
OCI_RESULT_CACHE_MAX_RSET_ROWS = 100000
Source {ORACLE_HOME}/rdbms/admin/dbmsrcad.sql
First Available 11.1
Constants

Name

Data Type Value
STATUS_CLSD VARCHAR(10) 'CLOSED'
STATUS_OPEN VARCHAR(10) 'OPEN'
STATUS_SYNC VARCHAR(10) 'SYNC'
Dependent Objects
ALL_OBJECTS GV$RESULT_CACHE_MEMORY
DBMS_RC_LIB GV$RESULT_CACHE_OBJECTS
GV$CLIENT_RESULT_CACHE_STATS GV$RESULT_CACHE_STATISTICS
GV$RESULT_CACHE_DEPENDENCY  

Result Cache Parameters
set linesize 121
col name format a30
col value format a30

SELECT name, value, issys_modifiable, isses_modifiable
FROM gv$parameter
WHERE name LIKE '%result%';

-- modifiable
-- ALTER SYSTEM SET result_cache_max_result = 5 SCOPE=BOTH;
-- options: AUTO, MANUAL, and FORCE: MANUAL is the default
-- ALTER SYSTEM SET result_cache_mode = 'AUTO' SCOPE=BOTH;
-- ALTER SYSTEM SET result_cache_remote_expiration = 0 SCOPE=BOTH;

-- not modifiable
-- client_result_cache_lag = 5000
-- result_cache_size = 'MANUAL'
-- client_result_cache_size = 0
Result Cache Statistics desc gv$result_cache_statistics

set linesize 121
col name format a30
col value format 999999

SELECT name, value
FROM gv$result_cache_statistics;
Security Model Execute is granted to the DBA role
 
BYPASS

S
et the bypass mode for the Result Cache. When bypass mode is "on", cached results are no longer used and new results are not saved. When turned off, the cache resumes normal operation.
dbms_result_cache.bypass(bypass_mode IN BOOLEAN);
BEGIN
  dbms_result_cache.bypass(FALSE);
  dbms_result_cache.flush;
END;
/

Note: With RAC this must be done on each node
 
FLUSH

Attempts to remove all the objects from the Result Cache, and depending on the arguments retains/releases the memory and retains/clears the statistics.

Overload 1
dbms_result_cache.flush(
retainMem IN BOOLEAN DEFAULT FALSE,
retainSta IN BOOLEAN DEFAULT FALSE)
RETURN BOOLEAN;
set serveroutput on

BEGIN
  IF dbms_result_cache.flush THEN
    dbms_output.put_line('Flush Successful');
  ELSE
    dbms_output.put_line('Flush Failure');
  END IF;
END;
/
Overload 2 dbms_result_cache.flush(
retainMem IN BOOLEAN DEFAULT FALSE,
retainSta IN BOOLEAN DEFAULT FALSE);
exec dbms_result_cache.flush(FALSE, TRUE);
 
INVALIDATE
Invalidates all the result-set objects that dependent upon the specified 
dependency object
Overload 1
dbms_result_cache.invalidate(owner IN VARCHAR2, name IN VARCHAR2)
RETURN NUMBER;
See DEMO below
Overload 2 dbms_result_cache.invalidate(owner IN VARCHAR2, name IN VARCHAR2);
See DEMO below
Overload 3 dbms_result_cache.invalidate(object_id IN POSITIVEN) RETURN NUMBER;
See DEMO below
Overload 4 dbms_result_cache.invalidate(object_id IN POSITIVEN);
See DEMO below
 
INVALIDATE_OBJECT
Invalidates the specified result-set object(s)

Overload 1
dbms_result_cache.invalidate_object(id IN POSITIVEN) RETURN NUMBER;
See DEMO below
Overload 2 dbms_result_cache.invalidate_object(id IN POSITIVEN);
See DEMO below
Overload 3 dbms_result_cache.invalidate_object(cache_id IN VARCHAR) RETURN NUMBER;
See DEMO below
Overload 4 dbms_result_cache.invalidate_object(cache_id IN VARCHAR);
See DEMO below
 
STATUS
Returns Result Cache status dbms_result_cache.status RETURN VARCHAR2
col status format a40

SELECT dbms_result_cache.status
FROM dual;
 
SQL Demos

Manual Result Cache Demo
SELECT dbms_result_cache.status
FROM dual;

col value format a30

SELECT name, value
FROM gv$parameter
WHERE name LIKE '%result%';

SELECT COUNT(*)
FROM gv$result_cache_objects;

/* if cached objects
set serveroutput on

BEGIN
  IF dbms_result_cache.flush THEN
    dbms_output.put_line('Flush Successful');
  ELSE
    dbms_output.put_line('Flush Failure');
  END IF;
END;
/

SELECT COUNT(*)
FROM gv$result_cache_objects;
*/


SELECT srvr_id
FROM (
  SELECT srvr_id, SUM(cnt) SUMCNT
  FROM (
    SELECT DISTINCT srvr_id, 1 AS CNT
    FROM servers
    UNION ALL
    SELECT DISTINCT srvr_id, 1
    FROM serv_inst)
  GROUP BY srvr_id)
WHERE sumcnt = 2;

conn / as sysdba

SELECT COUNT(*)
FROM gv$result_cache_objects;

conn uwclass/uwclass

SELECT /*+ RESULT_CACHE */ srvr_id
FROM (
  SELECT srvr_id, SUM(cnt) SUMCNT
  FROM (
    SELECT DISTINCT srvr_id, 1 AS CNT
    FROM servers
    UNION ALL
    SELECT DISTINCT srvr_id, 1
    FROM serv_inst)
  GROUP BY srvr_id)
WHERE sumcnt = 2;

-- cache object identification
conn / as sysdba

SELECT o.object_id, o.object_name, v.object_no
FROM all_objects o, gv$result_cache_dependency v
WHERE o.object_id = v.object_no;

SELECT COUNT(*)
FROM gv$result_cache_objects;

set linesize 121
set pagesize 25
col name format a45
col row_size_min format 99999
col cache_id format a30
col cache_key format a30

-- namespace can be SQL or PL/SQL
SELECT id, type, status, name, namespace
depend_count
FROM gv$result_cache_objects
ORDER BY 1;

SELECT id, creation_timestamp, depend_count, scan_count
FROM gv$result_cache_objects
ORDER BY 1;

SELECT id, block_count, scn, column_count, row_count, row_size_max,
row_size_min, row_size_avg
FROM gv$result_cache_objects
ORDER BY 1;

SELECT id, build_time, lru_number, object_no, invalidations, cache_id,
cache_key
FROM gv$result_cache_objects
ORDER BY 1;

SELECT id, offset, free, object_id
FROM gv$result_cache_memory
ORDER BY id;

exec dbms_result_cache.flush(FALSE, TRUE);

SELECT COUNT(*)
depend_count
FROM gv$result_cache_objects;

Automatic Result Cache Demo
conn / as sysdba

GRANT SELECT on gv_$result_cache_objects TO uwclass;

SELECT COUNT(*)
depend_count
FROM gv$result_cache_objects;

SELECT name, value
FROM gv$parameter
WHERE name LIKE '%result%';

ALTER SYSTEM SET result_cache_mode = 'AUTO' SCOPE=BOTH;

conn uwclass/uwclass

SELECT COUNT(*)
depend_count
FROM gv$result_cache_objects;

set linesize 121
col name format a25
col cache_id format a30
col name format a20
col status format a15

SELECT id, offset, free, object_id
FROM gv$result_cache_memory
ORDER BY id;

SELECT id, type, status, cache_id, name, scn
FROM gv$result_cache_objects
ORDER BY 1;

SELECT MAX(SUBSTR(netaddress,1,3))
FROM servers;

SELECT id, type, status, cache_id, name, scn
FROM gv$result_cache_objects
ORDER BY 1;

SELECT MAX(line_number)
FROM airplanes
WHERE customer_id = 'DAL';


-- sequentially invalidate objects using multiple overloads
 
PL/SQL Demos

Manual PL/SQL Invocation
SELECT dbms_result_cache.status
FROM dual;

SELECT name, value
FROM gv$parameter
WHERE name LIKE '%result%';

SELECT COUNT(*)
FROM gv$result_cache_objects;

CREATE OR REPLACE FUNCTION nocache(p_srvr_id IN servers.srvr_id%TYPE) RETURN BOOLEAN IS
 srvrow servers%ROWTYPE;
BEGIN
  SELECT *
  INTO srvrow
  FROM servers
  WHERE srvr_id = p_srvr_id;

  RETURN TRUE;
EXCEPTION
  WHEN OTHERS THEN
    RETURN FALSE;
END nocache;
/

set timing on

DECLARE
 b BOOLEAN;
BEGIN
  FOR i IN 1 .. 10 LOOP
    FOR i IN 1 .. 618 LOOP
      IF nocache(i) THEN
        NULL;
      END IF;
    END LOOP;
  END LOOP;
END;
/

CREATE OR REPLACE FUNCTION rcache(p_srvr_id IN servers.srvr_id%TYPE) RETURN BOOLEAN RESULT_CACHE RELIES_ON(servers) IS
 srvrow servers%ROWTYPE;
BEGIN
  SELECT *
  INTO srvrow
  FROM servers
  WHERE srvr_id = p_srvr_id;

  RETURN TRUE;
EXCEPTION
  WHEN OTHERS THEN
    RETURN FALSE;
END rcache;
/

set timing on

DECLARE
 b BOOLEAN;
BEGIN
  FOR i IN 1 .. 10 LOOP
    FOR i IN 1 .. 618 LOOP
      IF rcache(i) THEN
        NULL;
      END IF;
    END LOOP;
  END LOOP;
END;
/
 
Related Topics
Hints
Table
 
   Home |    Search |    Code Library |    Sponsors |    Privacy |    Terms of Use |    Contact Us    © 2003 - 2024 psoug.org
-----