Internal_Function with Encryption in SQL PLAN

Sometimes,the columns are decrypted as a result and decrypt functions (appears as INTERNAL_FUNCTION in the execution plan) are applied on them, which can lead to poor approximations of column selectivity, leading to improper plans. This happens mostly when the encrypted columns are using SALT to encrypt the data, but it can happen for other reasons as well, including bugs.

Bug:7147087 AFTER ENABLING TDE, EXECUTION PLAN CHANGES FOR THE WORSE

and it can be recognized from the following symptoms:

1. both tables participating in a join have encrypted columns.
2. there is at least a join condition with encrypted columns at both ends.
3. the second table has an index on the join column(s).
4. the INTERNAL_FUNCTION is applied to the encrypted columns in the join in the second table and the execution plan that used to be an INDEX UNIQUE SCAN on the unenecrypted columns turns into an INDEX RANGE SCAN or FULL TABLE SCAN.

Scenario 2: Pushed Predicates

The second known TDE performance bug is the one when the queries are using pushed predicates on encrypted columns inside explicit or implicit views and the encrypted column values are decrypted to filter out the values instead of encrypting the pushed predicates. This situation is met when:

1. external predicates are pushed into views
2. the execution plan presents predicate of the form INTERNAL_FUNCTION(column) = ;

On the other hand, INTERNAL_FUNCTION may consume more memory and cpu than normal

[oracle@rh2 admin]$ pwd
/s01/oracle/product/11.2.0/dbhome_1/network/admin


[oracle@rh2 admin]$ cat sqlnet.ora 
ENCRYPTION_WALLET_LOCATION=
  (SOURCE=(METHOD=FILE)(METHOD_DATA=
    (DIRECTORY=/s01/wallet)))


SQL> ALTER SYSTEM SET ENCRYPTION KEY AUTHENTICATED BY "oracle";

System altered.



SQL> conn maclean/maclean
Connected.

SQL> create table enctab (t1 int encrypt);
Table created.

SQL> select * from enctab;

no rows selected


Execution Plan
----------------------------------------------------------
Plan hash value: 3026244987

----------------------------------------------------------------------------
| Id  | Operation         | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |        |     1 |    47 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS FULL| ENCTAB |     1 |    47 |     2   (0)| 00:00:01 |
----------------------------------------------------------------------------

Note
-----
   - dynamic sampling used for this statement (level=2)


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

SQL> select * from enctab where t1=10;

no rows selected


Execution Plan
----------------------------------------------------------
Plan hash value: 3026244987

----------------------------------------------------------------------------
| Id  | Operation         | Name   | Rows  | Bytes | Cost (%CPU)| Time     |
----------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |        |     1 |    47 |     2   (0)| 00:00:01 |
|*  1 |  TABLE ACCESS FULL| ENCTAB |     1 |    47 |     2   (0)| 00:00:01 |
----------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter(INTERNAL_FUNCTION("T1")=10)

Note
-----
   - dynamic sampling used for this statement (level=2)


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

SQL> desc enctab;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 T1                                                 NUMBER(38) ENCRYPT


SQL> col WRL_PARAMETER for a20
SQL> set linesize 140
SQL> select * from V$ENCRYPTION_WALLET;

WRL_TYPE             WRL_PARAMETER        STATUS
-------------------- -------------------- ------------------
file                 /s01/wallet          OPEN



Posted

in

by

Tags:

Comments

2 responses to “Internal_Function with Encryption in SQL PLAN”

  1. Slava Avatar
    Slava

    We might have the issue you described in your post – bug 7147087. The columns on first and second table are of the same type – number. When I explicitly converted column on first table using function to_number: to_number(a.id) = b.id, instead of a.id=b.id – the execution plan changed back to using INDEX, not FULL TABLE SCAN. I’m not sure now that the reason was in encryption. Do you think that data type conversion function will help if both columns are encrypted?

Leave a Reply

Your email address will not be published. Required fields are marked *