DOC HOME SITE MAP MAN PAGES GNU INFO SEARCH PRINT BOOK
 

(mysql.info.gz) example-Maximum-column-group-row

Info Catalog (mysql.info.gz) example-Maximum-column-group (mysql.info.gz) Examples (mysql.info.gz) example-user-variables
 
 3.6.4 The Rows Holding the Group-wise Maximum of a Certain Field
 ----------------------------------------------------------------
 
 "For each article, find the dealer or dealers with the most expensive
 price."
 
 In standard SQL (and as of MySQL 4.1), the problem can be solved with a
 subquery 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 versions prior to 4.1, it's best do it in several steps:
 
   1. Get the list of (article,maxprice) pairs.
 
   2. For each article, get the corresponding rows that have the stored
      maximum price.
 
 This can easily be done with a temporary table and a join:
 
      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 called 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 be made a bit more efficient by doing the
 splitting of the concatenated column in the client.
 
Info Catalog (mysql.info.gz) example-Maximum-column-group (mysql.info.gz) Examples (mysql.info.gz) example-user-variables
automatically generated byinfo2html