Mohamed Houri’s Oracle Notes

December 18, 2019

Scalar subquery caching : the select from dual trick

Filed under: Oracle — hourim @ 3:00 pm

This short note explains why you should think about wrapping your PL/SQL function calls in a SELECT FROM DUAL so that you will get the performance benefit of scalar subquery caching whenever possible.

Recursive calls

Here’s below a real-life query running under a 12cR1 Exadata machine and using a call to a PL/SQL function in line number 8 below:

SQL> SELECT /*+ gather_plan_statistics */
2     a.xy_etp_dat_deb,
3     a.xy_etp_num,
4     a.xy_bat_id
5  FROM
6     sp_xy_exp_etp_exe a
7  WHERE
8       a.xy_bat_id = f_get_id('BJOBD176')
9   AND a.xy_etp_dat_deb = (select
10                               max(b.xy_etp_dat_deb)
11                           from sp_xy_exp_etp_exe b
12                           where a.xy_bat_id = b.xy_bat_id
13                           )
14   AND a.xy_etp_num     = (select
15                              max(c.xy_etp_num)
16                           from sp_xy_exp_etp_exe c
17                           where c.xy_bat_id    = a.xy_bat_id
18                           and c.xy_etp_dat_deb = a.xy_etp_dat_deb
19                           );

Elapsed: 00:00:01.82

Statistics
----------------------------------------------------------
18605  recursive calls
0  db block gets
297806  consistent gets
0  physical reads
0  redo size
482  bytes sent via SQL*Net to client
372  bytes received via SQL*Net from client
2  SQL*Net roundtrips to/from client
1  sorts (memory)
0  sorts (disk)
1  rows processed

I was immediately intrigued by the 18605 recursive calls that were systematically appearing at each execution of the above query. Therefore, I started trying to figure out the root cause of those recursive calls. The corresponding row-source execution plan is:

Plan hash value: 1967369873
--------------------------------------------------------------------------------------
| Id  | Operation                     | Name              | Starts | E-Rows | A-Rows |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |                   |      1 |        |      1 |
|*  1 |  FILTER                       |                   |      1 |        |      1 |
|*  2 |   HASH JOIN                   |                   |      1 |      1 |      1 |
|*  3 |    TABLE ACCESS STORAGE FULL  | SP_XY_EXP_ETP_EXE |      1 |     63 |     76 | --> this
|   4 |    VIEW                       | VW_SQ_1           |      1 |    296 |    296 |
|   5 |     SORT GROUP BY             |                   |      1 |    296 |    296 |
|   6 |      TABLE ACCESS STORAGE FULL| SP_XY_EXP_ETP_EXE |      1 |  18697 |  18605 | --> this
|   7 |   SORT AGGREGATE              |                   |      1 |      1 |      1 |
|*  8 |    TABLE ACCESS STORAGE FULL  | SP_XY_EXP_ETP_EXE |      1 |      1 |      1 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"."XY_ETP_NUM"=)
2 - access("A"."XY_ETP_DAT_DEB"="MAX(B.XY_ETP_DAT_DEB)" AND "A"."XY_BAT_ID"="ITEM_1")
3 - filter("A"."XY_BAT_ID"="F_GET_ID"('BJOBD176'))
8 - filter(("C"."XY_ETP_DAT_DEB"=:B1 AND "C"."XY_BAT_ID"=:B2))

I don’t think that the 18605 A-Rows at operation Id n°6 and the 18605 recursive calls are a result of a mere coincidence. They are inevitably related to each other. Let’s then try to find out this relationship. One way to do that is to look at a 10046-trace of the above query:

SQL> alter session set tracefile_identifier ='QueryRecursiveCalls';

SQL> @46on 12
SQL –- execute query here
SQL> @46off

The TKRPOFED trace file shows the followings:

SELECT /*+ gather_plan_statistics */
a.xy_etp_dat_deb,
a.xy_etp_num,
a.xy_bat_id
FROM
sp_xy_exp_etp_exe a
WHERE
a.xy_bat_id = f_get_id('BJOBD176')
AND a.xy_etp_dat_deb = (select
max(b.xy_etp_dat_deb)
from sp_xy_exp_etp_exe b
where a.xy_bat_id = b.xy_bat_id)
AND a.xy_etp_num     = (select
max(c.xy_etp_num)
from sp_xy_exp_etp_exe c
where c.xy_bat_id    = a.xy_bat_id
and c.xy_etp_dat_deb = a.xy_etp_dat_deb)

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.02       0.02          0         12          0           0
Execute      1      0.00       0.00          0          0          0           0
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        2      0.02       0.02          0         12          0           0

SQL ID: 5gb8jzxq0zcj4 Plan Hash: 1613371837

SELECT XY_BAT_ID
FROM
SP_XY_EXP_BAT WHERE XY_BAT_NOM = :B1

call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute  11146      0.93       0.95          0          0          0           0
Fetch    11146      0.83       0.90          0     178336          0       11146
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total    22293      1.77       1.85          0     178336          0       11146

As you we can see, there is a recursive SELECT against SP_XY_EXP_BAT table consuming almost all the total time of the query (1.85 seconds). This recursive SELECT, identified by SQL_ID 5gb8jzxq0zcj4, is nothing else than the content of the PL/SQL function used in line number 8 of the original main query and which I am reproducing here below:

WHERE
a.xy_bat_id = f_get_id('BJOBD176');

The capital bind variable :B1 in the TKPROF trace file represents another indication of a SQL embedded in PL/SQL. I can even get the captured value of this bind variable as shown below:

col value_string format a10
col last_captured format a20
select
last_captured
,value_string
from
v$sql_bind_capture
where sql_id = '5gb8jzxq0zcj4';

LAST_CAPTURED        VALUE_STRI
-------------------- ----------
05/08/19             BJOBD176

While the number of executions of the recursive SELECT shown in the TKPROF (11,146) is not exactly the number I was expecting i.e. 18,605, I can, nevertheless, see that the number of executions of the corresponding SQL_ID (5gb8jzxq0zcj4) stored in memory is exactly 18,605

SQL> @gv$sql
Enter value for sql_id: 5gb8jzxq0zcj4

SQL_ID        CHILD_NUMBER PLAN_HASH_VALUE TO_CHAR(P.LAST_ACTI EXECUTIONS
------------- ------------ --------------- ------------------- ----------
5gb8jzxq0zcj4            0      1613371837 05/08/2019 11:27:19      18605

So far, we have identified that the 18605 recursive calls represent simply the 18605 executions of predicate n°3 above which involves the call to the PL/SQL function. But what is, exactly, the relationship between those 18605 recursive calls and the 18605 A-Rows of line 6 in the above execution plan?

The 18605 recursive calls are strongly related to the number of rows present in the SP_XY_EXP_ETP_EXE table.

SQL> select count(1) from SP_XY_EXP_ETP_EXE;

COUNT(1)
----------
18605

Indeed, the PL/SQL function was called as many times as there are rows in this table producing 76 rows as confirmed via the A-Rows column of operation at line n°3 in the above execution plan:

SQL> select count(1) from SP_XY_EXP_ETP_EXE
where xy_bat_id = f_get_id('BJOBD176');

COUNT(1)
----------
76

How to fix the problem while still using the PL/SQL function?

The problem resorts to the multiple executions (18605) of the predicate n°3 on table SP_XY_EXP_ETP_EXE:

3 - filter("A"."XY_BAT_ID"="F_GET_ID"('BJOBD176'))

This happens even though the input to the function, BJOBD176, is constant.

If we surround the call to that function with a SELECT FROM DUAL Oracle will use scalar subquery caching producing, as such, a massive reduction in the number of calls to that function as the following proves:

SELECT /*+ gather_plan_statistics */
a.xy_etp_dat_deb,
a.xy_etp_num,
a.xy_bat_id
FROM
sp_xy_exp_etp_exe a
WHERE
a.xy_bat_id = (select f_get_id('BJOBD176') from dual)
AND a.xy_etp_dat_deb = (select
max(b.xy_etp_dat_deb)
from sp_xy_exp_etp_exe b
where a.xy_bat_id = b.xy_bat_id
)
AND a.xy_etp_num     = (select
max(c.xy_etp_num)
from sp_xy_exp_etp_exe c
where c.xy_bat_id    = a.xy_bat_id
and c.xy_etp_dat_deb = a.xy_etp_dat_deb
);

Elapsed: 00:00:00.02 --> drastic execution time reduction
--------------------------------------------------------------------------------------
| Id  | Operation                     | Name              | Starts | E-Rows | A-Rows |
--------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT              |                   |      1 |        |      1 |
|*  1 |  FILTER                       |                   |      1 |        |      1 |
|*  2 |   HASH JOIN                   |                   |      1 |      1 |      1 |
|*  3 |    TABLE ACCESS STORAGE FULL  | SP_XY_EXP_ETP_EXE |      1 |     63 |     76 |
|   4 |     FAST DUAL                 |                   |      1 |      1 |      1 |
|   5 |    VIEW                       | VW_SQ_1           |      1 |    296 |    296 |
|   6 |     SORT GROUP BY             |                   |      1 |    296 |    296 |
|   7 |      TABLE ACCESS STORAGE FULL| SP_XY_EXP_ETP_EXE |      1 |  18697 |  18605 |
|   8 |   SORT AGGREGATE              |                   |      1 |      1 |      1 |
|*  9 |    TABLE ACCESS STORAGE FULL  | SP_XY_EXP_ETP_EXE |      1 |      1 |      1 |
--------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
1 - filter("A"."XY_ETP_NUM"=)
2 - access("A"."XY_ETP_DAT_DEB"="MAX(B.XY_ETP_DAT_DEB)" AND"A"."XY_BAT_ID"="ITEM_1")
3 - storage("A"."XY_BAT_ID"=)
filter("A"."XY_BAT_ID"=)
9 - filter(("C"."XY_ETP_DAT_DEB"=:B1 AND "C"."XY_BAT_ID"=:B2))

Statistics
----------------------------------------------------------
1  recursive calls
0  db block gets
142  consistent gets
0  physical reads
0  redo size
482  bytes sent via SQL*Net to client
372  bytes received via SQL*Net from client
2  SQL*Net roundtrips to/from client
1  sorts (memory)
0  sorts (disk)
1  rows processed

Surrounding the call to the function with a select from dual allows Oracle to cache the result of the function for identical results. Therefore, the number of recursive calls drops from 18605 to only a single call and the query completes in about 2 milli-seconds instead of 2 seconds when scalar subquery caching was not possible.

Summary

As explained by Tom Kyte in this excellent article I can confirm that I have, almost always, improved the performance of my queries when I wrapped the PL/SQL function call into a SELECT FROM DUAL. This trick allows us to get the performance benefit of the scalar subquery cache.
In the next article I will show you what happens to the real-life query when I have replaced the PL/SQL function call by its content.

1 Comment »

  1. Great Mohamed.
    Thanks for sharing.

    Comment by Yahya — December 18, 2019 @ 8:05 pm | Reply


RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Google photo

You are commenting using your Google account. Log Out /  Change )

Twitter picture

You are commenting using your Twitter account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud Oracle's blog

Just another Oracle blog : Database topics and techniques

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)

%d bloggers like this: