Task: For each article, find the dealer or dealers with the most expensive price.
This problem can be solved with a subquery like this one:
Press CTRL+C to copySELECT article, dealer, price FROM shop s1 WHERE price=(SELECT MAX(s2.price) FROM shop s2 WHERE s1.article = s2.article) ORDER BY article; +---------+--------+-------+ | article | dealer | price | +---------+--------+-------+ | 0001 | B | 3.99 | | 0002 | A | 10.99 | | 0003 | C | 1.69 | | 0004 | D | 19.95 | +---------+--------+-------+
The preceding example uses a correlated subquery, which can be
inefficient (see Section 15.2.15.7, “Correlated Subqueries”). Other
possibilities for solving the problem are to use an uncorrelated
subquery in the FROM
clause, a LEFT
JOIN
, or a common table expression with a window
function.
Uncorrelated subquery:
Press CTRL+C to copySELECT s1.article, dealer, s1.price FROM shop s1 JOIN ( SELECT article, MAX(price) AS price FROM shop GROUP BY article) AS s2 ON s1.article = s2.article AND s1.price = s2.price ORDER BY article;
LEFT JOIN
:
Press CTRL+C to copySELECT s1.article, s1.dealer, s1.price FROM shop s1 LEFT JOIN shop s2 ON s1.article = s2.article AND s1.price < s2.price WHERE s2.article IS NULL ORDER BY s1.article;
The LEFT JOIN
works on the basis that when
s1.price
is at its maximum value, there is no
s2.price
with a greater value and thus the
corresponding s2.article
value is
NULL
. See Section 15.2.13.2, “JOIN Clause”.
Common table expression with window function:
Press CTRL+C to copyWITH s1 AS ( SELECT article, dealer, price, RANK() OVER (PARTITION BY article ORDER BY price DESC ) AS `Rank` FROM shop ) SELECT article, dealer, price FROM s1 WHERE `Rank` = 1 ORDER BY article;