MySQL Forums
Forum List  »  Performance

Re: Workaround for left join against a subquery?
Posted by: Björn Steinbrink
Date: March 21, 2007 09:36PM

OK, here's a try late at night... :) (Using MySQL 5.0.32)
I've splitted the query into two parts, one for part id 1 (which is special) and one for part id > 1 (assuming that part id 0 is not used, otherwise, use != 1 instead of > 1).

Version 1, using a dependent subquery.
SELECT
    p.id,
    (SELECT
        MIN(i.id)
    FROM
        inventory i 
    LEFT JOIN 
        parts p2 ON p2.id = i.partid 
    WHERE
        p2.id IS NULL OR p2.id = 1
    ) AS nextFIFOitemid
FROM
    parts p
WHERE
    p.id = 1
UNION
SELECT
    p.id,
    (SELECT 
        MIN(i.id) 
    FROM 
        inventory i 
    LEFT JOIN 
        parts p2 ON p2.id = i.partid 
    WHERE 
        p2.id = p.id
    ) AS nextFIFOitemid 
FROM 
    parts p 
WHERE 
    p.id > 1 
GROUP BY 
    p.id 
LIMIT 5;

Version 2, using a derived table:
SELECT
    p.id, 
    (SELECT 
        MIN(i.id) 
    FROM 
        inventory i 
    LEFT JOIN 
        parts p2 ON p2.id = i.partid 
    WHERE 
        p2.id IS NULL OR p2.id = 1
    ) AS nextFIFOitemid 
FROM 
    parts p 
WHERE 
    p.id = 1 
UNION 
SELECT 
    p.id, 
    nextFIFOitemid 
FROM 
    parts p 
LEFT JOIN
    (SELECT 
        partid, 
        MIN(i.id) AS nextFIFOitemid 
    FROM 
        inventory i 
    INNER JOIN 
        parts p2 ON p2.id = i.partid 
    GROUP BY 
        i.partid
    ) AS i2 ON i2.partid = p.id 
WHERE 
    p.id > 1 
GROUP BY 
    p.id 
LIMIT 5;

They both produce the same result as your query, but you should proof read them, I'm not sure if I got the special "NULL" condition for non-existing parts right.

The first version is slightly slower with the data you provided, but the second might outperform it with bigger datasets (didn't care to test that). For either version you'll want an index on inventory(partid,id) to get maximum performance.

If you don't actually care about the result for partid 1, just drop the first part of the UNION and only use the second SELECT, that's even faster.

Options: ReplyQuote


Subject
Views
Written By
Posted
Re: Workaround for left join against a subquery?
2243
March 21, 2007 09:36PM


Sorry, you can't reply to this topic. It has been closed.

Content reproduced on this site is the property of the respective copyright holders. It is not reviewed in advance by Oracle and does not necessarily represent the opinion of Oracle or any other party.