Oracle SQL
  • LICENSE

Deterministic function vs scalar subquery caching. Part 3

Posted on March 13, 2013 by Sayan Malakshinov Posted in deterministic functions, oracle, scalar subquery caching 2,795 Page views 0 Comments

In previous parts i already point out that:

  1. Both mechanisms are based on hash functions.
  2. Deterministic caching depends on fetch size(arraysize) – results cached only within one fetch call, ssc has no this limitation.
  3. Hash collisions depends on the single parameter “_query_execution_cache_max_size” for both mechanizms, but they are more frequent in SSC.
  4. Oracle doesn’t keep last result of deterministic functions as it does for scalar subquery caching
  5. Caching of deterministic functions results turns off after a certain number of attempts to get the value from the cache. But SSC always returns results from cache if values already cached.

Upd 2015-02-19:
A couple additions about deterministic functions:

  • Deterministic functions, result_cache and operators
  • How works optimization of loops in PL/SQL in 11g: Part 1. Deterministic functions

Today’s post is just addition to previous topics:

I wrote about turning caching off after many unsuccessfull attempts to get value from cache, but i didn’t say what it is the number. In fact caching of deterministic functions also depends on two another hidden parameters:

1
2
3
4
5
6
SQL> @param_ plsql%cach
 
NAME                                 VALUE        DEFLT    TYPE       DESCRIPTION
------------------------------------ ------------ -------- ---------- ------------------------------------------------------------------
_plsql_cache_enable                  TRUE         TRUE     boolean    PL/SQL Function Cache Enabled
_plsql_minimum_cache_hit_percent     20           TRUE     number     plsql minimum cache hit percentage required to keep caching active

First parameter “_plsql_cache_enable” is just a parameter which enables/disables this caching mechanism.
But the second parameter – “_plsql_minimum_cache_hit_percent” – is responsible for the percentage of unsuccessful attempts which disables caching.

I will show their effects with the example from the previous post:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
-- set this parameter to big value for maximizing caching:
alter session set "_query_execution_cache_max_size" = 131072;
-- log table clearing:
truncate table t_params;
-- test with percentage = 50
alter session set "_plsql_minimum_cache_hit_percent"=50;
select sum(f_deterministic(n)) fd
from
  xmltable('1 to 10000,1 to 10000'
           columns n int path '.'
          );
  
select 10000-count(count(*)) "Count of cached results"
from t_params
group by p
having count(*)>1;
/*
Count of cached results
-----------------------
                      0
*/
-- now i change cache hit percentage parameter to 0:
alter session set "_plsql_minimum_cache_hit_percent"=0;
truncate table t_params;
select sum(f_deterministic(n)) fd
from
  xmltable('1 to 10000,1 to 10000'
           columns n int path '.'
          );
  
select 10000-count(count(*)) "Count of cached results"
from t_params
group by p
having count(*)>1;
/*
Count of cached results
-----------------------
                   2039
*/
deterministic functions oracle oracle undocumented behaviour query optimizing
« How works optimization of loops in PL/SQL in 11g: Part 1. Deterministic functions
Unresolved quiz: Avoiding in-list iterator »
Page views: 2,795
photo Sayan Malakshinov

Oracle ACE Pro Oracle ACE Pro Alumni

DEVVYOracle Database Developer Choice Award winner

Oracle performance tuning expert

UK / Cambridge

LinkedIn   Twitter
sayan@orasql.org

Recent Posts

  • Oracle Telegram Bot
  • Partition Pruning and Global Indexes
  • Interval Search: Part 4. Dynamic Range Segmentation – interval quantization
  • Interval Search Series: Simplified, Advanced, and Custom Solutions
  • Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index

Popular posts

  • Amazing optimization of getting distinct values from the index, and TopN for each of them
    2012/09/21 by Sayan Malakshinov: 12k views
  • Oracle diagnostic events — Cheat sheet
    2021/05/20 by Sayan Malakshinov: 9.2k views
  • Deterministic functions, result_cache and operators
    2014/03/31 by Sayan Malakshinov: 8.8k views
  • Deterministic function vs scalar subquery caching. Part 1
    2013/02/10 by Sayan Malakshinov: 8.6k views
  • Differences between integer(int) in SQL and PL/SQL
    2012/11/10 by Sayan Malakshinov: 8.1k views
  • SQL*Plus tips #5: sql_text/sql_fulltext formatting(sql beatifier)
    2013/04/29 by Sayan Malakshinov: 7.9k views
  • Top-N again: fetch first N rows only vs rownum
    2018/12/30 by Sayan Malakshinov: 7.3k views
  • SQL*Plus tips #6: Colorizing output
    2013/05/22 by Sayan Malakshinov: 5.9k views
  • SYS_OP_MAP_NONNULL is in the documentation now
    2014/02/10 by Sayan Malakshinov: 4.3k views
  • Workaround for deadlock with select for update order by on 11.2.0.2-11.2.0.3
    2013/02/16 by Sayan Malakshinov: 4.3k views
  • SQL*Plus tips #4: Branching execution
    2013/04/17 by Sayan Malakshinov: 3.9k views
  • SQL*Plus tips. #1
    2013/03/29 by Sayan Malakshinov: 3.7k views

Recent Comments

  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index
  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Part 2. Dynamic Range Segmentation – Simplified
  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Optimizing Date Range Queries – Part 1
  • Oracle SQL | Interval Search Series: Simplified, Advanced, and Custom Solutions on Interval Search: Part 2. Dynamic Range Segmentation – Simplified
  • Oracle SQL | Interval Search: Part 2. Dynamic Range Segmentation – Simplified on Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index

Blogroll

  • Alex Fatkulin
  • Alexander Anokhin
  • Andrey Nikolaev
  • Charles Hooper
  • Christian Antognini
  • Coskan Gundogar
  • David Fitzjarrell
  • Igor Usoltsev
  • Jonathan Lewis
  • Karl Arao
  • Mark Bobak
  • Martin Bach
  • Martin Berger
  • Neil Chandler
  • Randolf Geist
  • Richard Foote
  • Riyaj Shamsudeen
  • Tanel Poder
  • Timur Akhmadeev
  • Valentin Nikotin
©Sayan Malakshinov. Oracle SQL