How to resolve SQL object and column names all the way to base tables and columns in Oracle?

Tanel Poder

2007-09-16

Update: As this original article is from 2007, there are better options available in the modern times – for example DBMS_UTILITY.EXPAND_SQL_TEXT as explained by Maria Colgan’s blog entry here.

If you have been involved in tuning SQL code which you have never seen before, you are probably familiar with the challenges of understanding what the code is trying to do. This can be especially time consuming when the SQL references lots of views, which reference views, which reference more views etc. So there may be a large information gap between the SQL statement (like select * from some_crazy_10_level_view) and the actual execution plan (referencing 10s of tables, with evidence of query transformations).

So unless you see something really obvious from the execution plan, you need to start mapping the SQL query and view texts back to the physical base tables which Oracle eventually has to access. This can be a tedious and boring (!) process.

The good news is that in Oracle 10.2+ there’s a hidden parameter that can do this mapping task for us.

Update: It looks like 9.2.0.8 patchset also has this parameter (so I guess later patchsets of 10.1.0.x have it as well now)

Let’s see an example:

I create a view on a view to illustrate the point:

SQL> create view myview as select * from all_users;

View created.

Now let’s set that parameter _dump_qbc_tree to 1 and run a query against the view:

SQL> alter session set "_dump_qbc_tree"=1;

Session altered.

SQL> select count(*) from myview;

  COUNT(*)
----------
        31

Now let’s look into the server process tracefile:

*** ACTION NAME:() 2007-09-16 12:19:57.500
*** MODULE NAME:(SQL*Plus) 2007-09-16 12:19:57.500
*** SERVICE NAME:(SYS$USERS) 2007-09-16 12:19:57.500
*** SESSION ID:(146.1984) 2007-09-16 12:19:57.500
QCSDMP: -------------------------------------------------------
QCSDMP:  SELECT: (qbc=2B8D1C28)
QCSDMP:    . (COUNT(*)) (opntyp=2 opndty=0)
QCSDMP:  FROM:
QCSDMP:    .MYVIEW
QCSDMP:      VQB:
QCSDMP:        SELECT: (qbc=2B8D163C)
QCSDMP:          .USERNAME
QCSDMP:        FROM:
QCSDMP:          .ALL_USERS
QCSDMP:            VQB:
QCSDMP:              SELECT: (qbc=2B8CAF78)
QCSDMP:                U.NAME (USERNAME)
QCSDMP:              FROM:
QCSDMP:                SYS.TS$ (TTS)
QCSDMP:                SYS.TS$ (DTS)
QCSDMP:                SYS.USER$ (U)

Here it is, the query text generated directly from parse tree, showing the base tables regardless that they had been hidden behind multiple views.

Also there’s few interesting things to note:

If you ran a SELECT * instead of SELECT COUNT(*) then you’d see all columns “propagated” all the way do the lowest layers of that query. Oracle is smart being lazy – it only requests for those columns which it needs.

Lets look into the execution plan of this query:

SQL> @x

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------
Plan hash value: 3268326079

------------------------------------------------------------------------------
| Id  | Operation            | Name  | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------
|   0 | SELECT STATEMENT     |       |     1 |    15 |    12   (9)| 00:00:01 |
|   1 |  SORT AGGREGATE      |       |     1 |    15 |            |          |
|*  2 |   HASH JOIN          |       |    29 |   435 |    12   (9)| 00:00:01 |
|*  3 |    HASH JOIN         |       |    29 |   348 |     8  (13)| 00:00:01 |
|   4 |     TABLE ACCESS FULL| TS$   |     8 |    24 |     4   (0)| 00:00:01 |
|*  5 |     TABLE ACCESS FULL| USER$ |    29 |   261 |     3   (0)| 00:00:01 |
|   6 |    TABLE ACCESS FULL | TS$   |     8 |    24 |     4   (0)| 00:00:01 |
------------------------------------------------------------------------------

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

   2 - access("U"."TEMPTS#"="TTS"."TS#")
   3 - access("U"."DATATS#"="DTS"."TS#")
   5 - filter("U"."TYPE#"=1)

20 rows selected.

Interestingly the nested views which we had in our query and QBC trace do not appear in the execution plan. This is because the QBC trace is dumped before any query transformations (such view merging) are applied. And this is exactly what we want – because we are interested in business logic of the query, not Oracle’s optimizations done under the hood.

When we disable simple view merging transformation which happened in our case, then we see execution plan matching the QBC trace:

SQL> alter session set "_simple_view_merging"=false;

Session altered.

SQL> select count(*) from myview;

  COUNT(*)
----------
        31

SQL> @x

PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------
Plan hash value: 259067589

------------------------------------------------------------------------------------
| Id  | Operation              | Name      | Rows  | Bytes | Cost (%CPU)| Time     |
------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT       |           |     1 |       |    12   (9)| 00:00:01 |
|   1 |  SORT AGGREGATE        |           |     1 |       |            |          |
|   2 |   VIEW                 | MYVIEW    |    29 |       |    12   (9)| 00:00:01 |
|   3 |    VIEW                | ALL_USERS |    29 |       |    12   (9)| 00:00:01 |
|*  4 |     HASH JOIN          |           |    29 |   435 |    12   (9)| 00:00:01 |
|*  5 |      HASH JOIN         |           |    29 |   348 |     8  (13)| 00:00:01 |
|   6 |       TABLE ACCESS FULL| TS$       |     8 |    24 |     4   (0)| 00:00:01 |
|*  7 |       TABLE ACCESS FULL| USER$     |    29 |   261 |     3   (0)| 00:00:01 |
|   8 |      TABLE ACCESS FULL | TS$       |     8 |    24 |     4   (0)| 00:00:01 |
------------------------------------------------------------------------------------

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

   4 - access("U"."TEMPTS#"="TTS"."TS#")
   5 - access("U"."DATATS#"="DTS"."TS#")
   7 - filter("U"."TYPE#"=1)

22 rows selected.

So, this _dump_qbc_tree parameter is definitely a handy tool aiding interpretation of complex queries and queries based on multiple layers of views, filling the gap between “raw” SQL statement and its physical execution plan.

Note that as this is an undocumented parameter, use it carefully in non-experimental environments.


  1. I am finally close to launching the completely rebuilt 2024 versions of my Linux & AOT classes in my Learning Platform! (Updates to SQL Tuning class in H2 2024):
    Advanced Oracle SQL Tuning training. Advanced Oracle Troubleshooting training, Linux Performance & Troubleshooting training. Check them out!
  2. Get randomly timed updates by email or follow Social/RSS