EmergencyEMERGENCY? Get 24/7 Help Now!

Possible optimization for sort_merge and UNION ORDER BY LIMIT

 | September 18, 2007 |  Posted In: Insight for Developers


Every so often you need to perform sort results retrieved from MySQL when your WHERE clause goes beyound col=const values which would allow MySQL to still use second portion of the index for the order by. Ranges as well as IN lists make this optimization impossible, not even speaking about index merge optimization. Lets look at this example:

As you can see MySQL 5.1.21 uses sort_merge to access the rows but it can’t use it together with order by efficiently.
I’d say this is limitation as for this case you well could be retrieving sorted streams by the indexes and doing merge sort to get resulted rows in sorted order. Once this is implemented similar approach could be used for optimizing ORDER BY with IN.

This original query (in memory data) takes 1sec. Let’s see how classic pre MySQL 5.0 solution – using UNION instead of single query works in this case:

The query looks scare but in fact in completes in 1.05 sec not significantly faster than sort index merge in this case.

As the query time implies MySQL is not smart enough in this case to “dive into” the union and add ORDER BY ORD LIMIT 10 to individual queries.
What if we do int manually ?

As you can see explain does not really change (it does not show if index is used for finding rows or sorting as well) but query speed goes to less than
0.01 sec.

So it is great optimization which you need to do manuall for the time being.

What is also interesting is the fact MySQL is unable to handle even basic UNION with limit (without order by) optimally – in creates result set for the union fully and when only takes 10 rows from it:

Such query takes about 0.9 sec on the test data. Another possible optimizer improvement to do.

P.S This post is inspired by Does MySQL Optimize UNION with LIMIT clause topic on our MySQL Forums.

Peter Zaitsev

Peter managed the High Performance Group within MySQL until 2006, when he founded Percona. Peter has a Master's Degree in Computer Science and is an expert in database kernels, computer hardware, and application scaling.


  • testing on my notebook and utest with more than 1,000,000 rows, with mysql 5.0.45

    (SELECT * FROM utest WHERE c1=5) union (SELECT * FROM utest WHERE c2=5) ORDER BY ord DESC LIMIT 10;
    10 rows in set (0.31 sec)

    (SELECT * FROM utest WHERE c1=5 ORDER BY ord DESC LIMIT 10) union (SELECT * FROM utest WHERE c2=5 ORDER BY ord DESC LIMIT 10) ORDER BY ord DESC LIMIT 10
    10 rows in set (0.25 sec)

    the speed is not so big differenet than you did

  • David,

    Can you do EXPLAIN on your queries ?

    0.25 sec is just very wrong time for such query as all what needs to be done in second query is fetching 10 rows by one index when 10 rows by another index and them sorting them.

  • Peter,
    Sorry I made a mistake. Finally the query
    (SELECT * FROM utest WHERE c1=5 ORDER BY ord DESC LIMIT 10) union (SELECT * FROM utest WHERE c2=5 ORDER BY ord DESC LIMIT 10) ORDER BY ord DESC LIMIT 10,takes only 0.03

  • thanks a lot i was searching for one of my query, i would love to specially thanks to Devid. because i just wanted query which he has posted here.
    many thanks.

  • I’m creating a shopping cart type system where users can add a bunch of products. It’s important that users can change the display order of products. This way they can showcase certain items on top.

    All of this is stored in the database obviously.

    There is a problem though, and it’s with the sort order storage in the database. For instance, if I have 5 products, I can set it like this:

    01 A
    10 B
    20 C
    30 D
    40 E

    The number is the “sort” field, and the letter is the “product” field. I’d then set an index for the “sort” field and the listings would be fast.

    Now, suppose I wanted to re-order E to position number two (right now it’s position number 5). I could do this:

    01 A
    05 E
    10 B
    20 C
    30 D

    The problem here is, if I keep re-sorting, I’d run out of numbers in between and will have to re-order everything. This can be a potential nightmare if I have thousands of products.

    Is there a better way of doing this?

Leave a Reply


Percona’s widely read Percona Data Performance blog highlights our expertise in enterprise-class software, support, consulting and managed services solutions for both MySQL® and MongoDB® across traditional and cloud-based platforms. The decades of experience represented by our consultants is found daily in numerous and relevant blog posts.

Besides specific database help, the blog also provides notices on upcoming events and webinars.
Want to get weekly updates listing the latest blog posts? Subscribe to our blog now! Submit your email address below and we’ll send you an update every Friday at 1pm ET.

No, thank you. Please do not ask me again.