Skip to Main Content

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Sunil Kumar.

Asked: July 28, 2016 - 1:06 am UTC

Last updated: February 20, 2019 - 11:27 am UTC

Version: 12c, 11g, 10g

Viewed 10K+ times! This question is

You Asked

Hi,

I have learned that there is a new LATERAL keyword available in 12c Version. However, trying to understand the usage of the same.

tried going through some links, but couldn't get complete picture. Syntax happy. Can you please help me.

and Chris said...

Oracle Database has used lateral internally for a while. Specifically this was to transform ANSI outer joins to Oracle outer joins where a direct translation isn't possible. For example, if your outer join included an OR:

select t1.x, t2.x from t1
left join t2
on   t1.x = t2.x or t1.y = t2.x


There isn't a way to convert this to Oracle syntax. So instead it became something like:

select T1.X X,subq.X X
from T1, lateral (
  (select T2.X X from T2
   where T1.X=T2.X or T1.Y=T2.X
  ) 
) (+) subq;


You can read more about this at:

http://optimizermagic.blogspot.co.uk/2007/12/outerjoins-in-oracle.html

Lateral is also part of the ANSI standard. So from a compliance point of view it makes sense to expose it. It is also useful for supporting CROSS APPLY which we introduced in 12c.

It's also useful when working with non-mergeable views. For example, in the following query Oracle fully processes the subquery before joining to t1:

select /*+ gather_plan_statistics */* from t1, (
  select * from t2
  minus 
  select * from t2
  where  y > 50
) t2
where t1.x = t2.x;

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

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------

EXPLAINED SQL STATEMENT:
------------------------
select /*+ gather_plan_statistics */* from t1, (   select * from t2
minus   select * from t2   where  y > 50 ) t2 where t1.x = t2.x

Plan hash value: 187374969

-----------------------------------------------------------------
| Id  | Operation             | Name | Starts | E-Rows | A-Rows |
-----------------------------------------------------------------
|   0 | SELECT STATEMENT      |      |      1 |        |     10 |
|*  1 |  HASH JOIN            |      |      1 |    100 |     10 |
|   2 |   TABLE ACCESS FULL   | T1   |      1 |      2 |      2 |
|   3 |   VIEW                |      |      1 |    100 |     50 |
|   4 |    MINUS              |      |      1 |        |     50 |
|   5 |     SORT UNIQUE       |      |      1 |    100 |    100 |
|   6 |      TABLE ACCESS FULL| T2   |      1 |    100 |    100 |
|   7 |     SORT UNIQUE       |      |      1 |     51 |     50 |
|*  8 |      TABLE ACCESS FULL| T2   |      1 |     51 |     50 |
-----------------------------------------------------------------

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

   1 - access("T1"."X"="T2"."X")
   8 - filter("Y">50)


In some cases there can be a big performance advantage to doing the join inside the subquery. Using the lateral operator enables this:

select /*+ gather_plan_statistics */* from t1, 
lateral(
  select * from t2
  where  t1.x = t2.x
  minus 
  select * from t2
  where  t1.x = t2.x
  and    y > 50
) t2;

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

PLAN_TABLE_OUTPUT
----------------------------------------------------------------------------------------------

EXPLAINED SQL STATEMENT:
------------------------
select /*+ gather_plan_statistics */* from t1, lateral(   select * from
t2   where  t1.x = t2.x   minus   select * from t2   where  t1.x = t2.x
  and    y > 50 ) t2

Plan hash value: 1689167383

----------------------------------------------------------------------------------------------
| Id  | Operation                               | Name            | Starts | E-Rows | A-Rows |
----------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                        |                 |      1 |        |     10 |
|   1 |  NESTED LOOPS                           |                 |      1 |     20 |     10 |
|   2 |   TABLE ACCESS FULL                     | T1              |      1 |      2 |      2 |
|   3 |   VIEW                                  | VW_LAT_A18161FF |      2 |     10 |     10 |
|   4 |    MINUS                                |                 |      2 |        |     10 |
|   5 |     SORT UNIQUE                         |                 |      2 |     10 |     20 |
|   6 |      TABLE ACCESS BY INDEX ROWID BATCHED| T2              |      2 |     10 |     20 |
|*  7 |       INDEX RANGE SCAN                  | I               |      2 |     10 |     20 |
|   8 |     SORT UNIQUE                         |                 |      2 |      5 |     10 |
|*  9 |      TABLE ACCESS BY INDEX ROWID BATCHED| T2              |      2 |      5 |     10 |
|* 10 |       INDEX RANGE SCAN                  | I               |      2 |     10 |     20 |
----------------------------------------------------------------------------------------------

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

   7 - access("T1"."X"="T2"."X")
   9 - filter("Y">50)
  10 - access("T1"."X"="T2"."X")


You can see that Oracle switches from two full scans of T2 to two index lookups of it. Possibly a huge saving!

And of course, like with cross apply, it may just make the query easier to write and/or understand. For example, you can take this rather convoluted way of converting a comma separated string to rows:

with strings as (
  select 'a,b,c' s from dual
)
select trim(regexp_substr(s.s, '[^,]+', 1, rws.column_value))  as v
from 
  strings s,
  table(cast(multiset(
      select level l from dual 
      connect by level <= length (regexp_replace(s.s, '[^,]+'))  + 1
    ) as sys.OdciNumberList )
  ) rws;

V
a      
b      
c 


Lateral removes the need for all the table cast nonsense. So you can rewrite it like:

with strings as (
  select 'a,b,c' s from dual
)
select trim(regexp_substr(s.s, '[^,]+', 1, rws.l)) as v
from 
  strings s,
  lateral(
    select level l from dual 
    connect by  level <= length (regexp_replace(s.s, '[^,]+'))  + 1
  ) rws;

V
a      
b      
c 


Though you might want to check out another method for doing this anyway:

https://stewashton.wordpress.com/2016/08/01/splitting-strings-surprise/

HT to Wayne Smith in development for helping with this!

Scripts to create the tables for the above example:

create table t1 as
  select rownum x from dual connect by level <= 2;
create table t2 as
  select mod(rownum, 10) x, rownum y from dual connect by level <= 100;
  
create index i on t2(x);
exec dbms_stats.gather_table_stats(user, 't1');
exec dbms_stats.gather_table_stats(user, 't2');

Rating

  (2 ratings)

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

Comments

Why so complex?

}ilvinas Vidmantas, February 22, 2017 - 4:33 pm UTC

with strings as (select 'a,b,c' s from dual)
select regexp_substr(s.s, '\w+', 1, LEVEL) as v
  from strings s
connect by level <= regexp_count(s.s, '\w+')

Chris Saxon
February 22, 2017 - 5:00 pm UTC

Well the OP was looking for examples of lateral!

And the simplified example doesn't really work if the source table has multiple rows:

with strings as (select 'a,b,c' s from dual union all select 'e, f' from dual)
select regexp_substr(s.s, '\w+', 1, LEVEL) as v
  from strings s
connect by level <= regexp_count(s.s, '\w+');

V
a
b
c
f
c
e
b
c
f
c

Lateral for Connect by clause

Rajeshwaran, Jeyabal, February 20, 2019 - 10:57 am UTC

Team,

Is that LATERAL syntax is not supported for CONNECT BY Clause?

using mutliset/cast/table clause

demo@ORA12C> select e1.empno,e1.ename,e1.sal,t2.column_value as hierarchy_sal
  2  from emp e1,
  3    table( cast(multiset(select sum(e2.sal)
  4        from emp e2
  5        start with e2.mgr = e1.empno or e2.empno = e1.empno
  6        connect by prior e2.empno = e2.mgr) as sys.odcinumberlist) ) t2
  7  /

     EMPNO ENAME             SAL HIERARCHY_SAL
---------- ---------- ---------- -------------
      7369 SMITH             800           800
      7499 ALLEN            1600          1600
      7521 WARD             1250          1250
      7566 JONES            2975         18775
      7654 MARTIN           1250          1250
      7698 BLAKE            2850         15950
      7782 CLARK            2450          5050
      7788 SCOTT            3000          5200
      7839 KING             5000         53050
      7844 TURNER           1500          1500
      7876 ADAMS            1100          1100
      7900 JAMES             950           950
      7902 FORD             3000          4600
      7934 MILLER           1300          1300

14 rows selected.


then using Lateral clause got into this error.

demo@ORA12C> select empno,ename,sal,hierarchy_sal
  2  from emp e1 ,lateral(
  3        select sum(e2.sal) as hierarchy_sal
  4        from emp e2
  5        start with e2.mgr = e1.empno or e2.empno = e1.empno
  6        connect by prior e2.empno = e2.mgr )
  7  /
      start with e2.mgr = e1.empno or e2.empno = e1.empno
                                                 *
ERROR at line 5:
ORA-00904: "E1"."EMPNO": invalid identifier


Chris Saxon
February 20, 2019 - 11:27 am UTC

I can't find an explicit doc reference. But this started working in 18c:


select * from v$version;

BANNER                                                                         CON_ID   
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production          0 
PL/SQL Release 12.2.0.1.0 - Production                                                0 
CORE 12.2.0.1.0 Production                                                            0 
TNS for Linux: Version 12.2.0.1.0 - Production                                        0 
NLSRTL Version 12.2.0.1.0 - Production                                                0 

select count(*)
from   hr.employees e1 ,lateral(
  select sum(e2.salary) as hierarchy_sal
  from   hr.employees e2
  start  with e2.manager_id = e1.employee_id or e2.employee_id = e1.employee_id
  connect by prior e2.employee_id = e2.manager_id 
);

SQL Error: ORA-00904: "E1"."EMPLOYEE_ID": invalid identifier



select banner from v$version;

BANNER                                                                   
Oracle Database 18c Enterprise Edition Release 18.0.0.0.0 - Production  

select count(*)
from   hr.employees e1 ,lateral(
  select sum(e2.salary) as hierarchy_sal
  from   hr.employees e2
  start  with e2.manager_id = e1.employee_id or e2.employee_id = e1.employee_id
  connect by prior e2.employee_id = e2.manager_id 
);

COUNT(*)   
       107 

More to Explore

Performance

Get all the information about database performance in the Database Performance guide.