Skip to Main Content
  • Questions
  • Selection from union view by table identifier

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Alexander.

Asked: September 17, 2018 - 4:30 pm UTC

Last updated: September 18, 2018 - 12:50 pm UTC

Version: 12.0.2

Viewed 1000+ times

You Asked

Hi,
I have a view like
create view V_TAB as 
(select 1 as id, value from TAB1
 union all
 select 2 as id, value from TAB2
);

I would expect Oracle be able to optimize the following query and execute a selection only on one table, since id value provided as a constant value -

select * from V_TAB where id=1;

but execution plan shows selection from both underlying tables -

------------------------------------------------------
| Id  | Operation                | Name              |
------------------------------------------------------
|   0 | SELECT STATEMENT         |                   |
|   1 |  VIEW                    |                   |
|   2 |   UNION-ALL              |                   |
|   3 |     TABLE ACCESS FULL    | TAB1              |
|*  4 |    FILTER                |                   |
|   5 |     TABLE ACCESS FULL    | TAB2              |
------------------------------------------------------


what is also interesting - the it uses strange filtering expression -
Predicate Information (identified by operation id):
---------------------------------------------------
4 - filter(NULL IS NOT NULL)

It looks like Oracle optimizer ignores the possibility of table restriction based on the view's constant values. May be there are some workarounds? My goal is to create a single view on the top of several similar tables and instead of several select statements different in table name use one select statement parameterized by table id. Another words I want to minimize my code and the same time do not add scans on unnecessary tables.
I.e. instead of
if p_id=1 then
  select count(*) into cnt from TAB1;
elsif p_id=2 then
  select count(*) into cnt from TAB2;
else
  cnt := 0;
end if;

use simple code
select count(*) into cnt from V_TAB where id=v_id;


and Chris said...

But the database is able to optimize your query as you want!

While both tables may appear in your plan, it only accesses one at runtime.

The predicate NULL IS NOT NULL => false. Which means that it doesn't do the operations under this filter.

You can verify this by looking at the execution plan for the query. This shows its runtime stats:

create or replace view V_TAB as 
(select 1 as id, dummy from dual
 union all
 select 2 as id, dummy from dual
);
set serveroutput off

select /*+ gather_plan_statistics */* from V_TAB where id=1;

select * 
from   table(dbms_xplan.display_cursor(null, null, 'ROWSTATS LAST'));

PLAN_TABLE_OUTPUT                                                   
SQL_ID  66w0ahf4hk0p4, child number 0                               
-------------------------------------                               
select /*+ gather_plan_statistics */* from V_TAB where id=2         
                                                                    
Plan hash value: 3824994890                                         
                                                                    
-----------------------------------------------------------------   
| Id  | Operation            | Name  | Starts | E-Rows | A-Rows |   
-----------------------------------------------------------------   
|   0 | SELECT STATEMENT     |       |      1 |        |      1 |   
|   1 |  VIEW                | V_TAB |      1 |      2 |      1 |   
|   2 |   UNION-ALL          |       |      1 |        |      1 |   
|*  3 |    FILTER            |       |      1 |        |      0 |   
|   4 |     TABLE ACCESS FULL| DUAL  |      0 |      1 |      0 |   
|   5 |    TABLE ACCESS FULL | DUAL  |      1 |      1 |      1 |   
-----------------------------------------------------------------   
                                                                    
Predicate Information (identified by operation id):                 
---------------------------------------------------                 
                                                                    
   3 - filter(NULL IS NOT NULL)                                     
                                   


Notice how the starts and A-rows columns show zero for Id four? This means this full scan of dual never happened!

Rating

  (1 rating)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Nice explanation

Alexander Zemerov, September 18, 2018 - 12:17 pm UTC

Thank you Chris - that was very nice explanation.
Actually I was always thinking that A-Rows shows number of rows produced by operation (result of filtration), not the number of actually scanned rows before filtration. Obviously I was wrong because if I was right the zero would appear only in FILTER line, not in TABLE ACCESS FULL.
Chris Saxon
September 18, 2018 - 12:50 pm UTC

A-rows is the number of rows produced. The following example queries a table with 100 rows. There's no index, so it must inspect all the rows. But the plan shows the output of zero:

set serveroutput off
create table t as 
  select level c1 from dual
  connect by level <= 100;
  
select /*+ gather_plan_statistics */* from t
where  c1 < 1;

select * 
from   table(dbms_xplan.display_cursor(null, null, 'ROWSTATS LAST'));

PLAN_TABLE_OUTPUT                                               
SQL_ID  c5xs76mp35qvq, child number 0                           
-------------------------------------                           
select /*+ gather_plan_statistics */* from t where  c1 < 1      
                                                                
Plan hash value: 2498539100                                     
                                                                
-------------------------------------------------------------   
| Id  | Operation         | Name | Starts | E-Rows | A-Rows |   
-------------------------------------------------------------   
|   0 | SELECT STATEMENT  |      |      1 |        |      0 |   
|*  1 |  TABLE ACCESS FULL| T    |      1 |      1 |      0 |   
-------------------------------------------------------------   
                                                                
Predicate Information (identified by operation id):             
---------------------------------------------------             
                                                                
   1 - filter("C1"<1) 


The key point in the union example is the Starts are also zero. That means this operation never took place.

More to Explore

Administration

Need more information on Administration? Check out the Administrators guide for the Oracle Database