Skip to Main Content
  • Questions
  • Sequence of selecting from ordered inner query

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Akash.

Asked: January 11, 2019 - 2:00 pm UTC

Last updated: January 13, 2019 - 6:06 am UTC

Version: 12.0.1

Viewed 1000+ times

You Asked

Hi Tom,

Does selecting from an inner query ,which has an order by clause, guarantee that the final output to be sorted by the order by column in inner query?

Select 
           * 
       from ( select 
                   * 
              from t 
              order by n);


Will final output be sorted by n ALWAYS?

Thanks

and Chris said...

Trivial example where the inner sort is NOT preserved:

create table t as 
  select level c1 , mod ( level, 4 ) c2 
  from   dual
  connect by level <= 100;
  
select c2, count(*) from (
  select * from t
  order  by c2
)
group  by c2;

C2   COUNT(*)   
   1         25 
   2         25 
   3         25 
   0         25 


To be 100% certain that the database returns the rows in the order you want, add an order by clause to your outermost select.

Rating

  (1 rating)

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

Comments

Quick and Correct

Akash Jain, January 11, 2019 - 5:26 pm UTC

Thanks Chris for the fast response.

That was a great example.

I knew that the outer query result might not be ordered by the inner query order by column(s) always.
But I was unable to build data and query to prove it. Wonder how you did it so quickly!!!

Thanks again.
Connor McDonald
January 13, 2019 - 6:06 am UTC

Glad we could help

More to Explore

SQL

The Oracle documentation contains a complete SQL reference.