Info Node: (mysql.info)example-Maximum-column-group-row
(mysql.info)example-Maximum-column-group-row
The Rows Holding the Group-wise Maximum of a Certain Field
----------------------------------------------------------
"For each article, find the dealer(s) with the most expensive price."
In ANSI SQL, I'd do it with a sub-query like this:
SELECT article, dealer, price
FROM shop s1
WHERE price=(SELECT MAX(s2.price)
FROM shop s2
WHERE s1.article = s2.article);
In MySQL it's best do it in several steps:
1. Get the list of (article,maxprice).
2. For each article get the corresponding rows that have the stored
maximum price.
This can easily be done with a temporary table:
CREATE TEMPORARY TABLE tmp (
article INT(4) UNSIGNED ZEROFILL DEFAULT '0000' NOT NULL,
price DOUBLE(16,2) DEFAULT '0.00' NOT NULL);
LOCK TABLES shop read;
INSERT INTO tmp SELECT article, MAX(price) FROM shop GROUP BY article;
SELECT shop.article, dealer, shop.price FROM shop, tmp
WHERE shop.article=tmp.article AND shop.price=tmp.price;
UNLOCK TABLES;
DROP TABLE tmp;
If you don't use a `TEMPORARY' table, you must also lock the 'tmp'
table.
"Can it be done with a single query?"
Yes, but only by using a quite inefficient trick that I call the
"MAX-CONCAT trick":
SELECT article,
SUBSTRING( MAX( CONCAT(LPAD(price,6,'0'),dealer) ), 7) AS dealer,
0.00+LEFT( MAX( CONCAT(LPAD(price,6,'0'),dealer) ), 6) AS price
FROM shop
GROUP BY article;
+---------+--------+-------+
| article | dealer | price |
+---------+--------+-------+
| 0001 | B | 3.99 |
| 0002 | A | 10.99 |
| 0003 | C | 1.69 |
| 0004 | D | 19.95 |
+---------+--------+-------+
The last example can, of course, be made a bit more efficient by doing
the splitting of the concatenated column in the client.