This is a read-only copy of the MariaDB Knowledgebase generated on 2024-11-15. For the latest, interactive version please visit https://mariadb.com/kb/.

MAX(<date>) / GROUP BY behaviour...

I'm attempting to retrieve the latest records for each pairs for key1 and key2 using the following select query:

SELECT `key1`, `key2`, MAX(`key3`) AS `date`, `date1`, `date2`, `date3`, `date4` 
FROM `test`
GROUP BY `key1`, `key2`;

The results I get as shown below are somewhat confusing. I do get the latest date but the values for the columns date1, date2, date3 and date4 are not matching the records I would expect from the database.

key1key2datedate1date2date3date4
100B2099-01-012000-07-112000-12-312000-07-112000-12-31
400B2099-05-042000-07-182000-07-182000-07-182000-07-18

I'm no SQL expert so Any help would be quite appreciated !

Robert.

Bellow is a sample DB

Server version: 5.5.52-MariaDB - MariaDB Server

CREATE TABLE IF NOT EXISTS `test` (
  `key1` int(10) unsigned NOT NULL,
  `key2` varchar(5) NOT NULL,
  `key3` date NOT NULL,
  `date1` date DEFAULT NULL,
  `date2` date DEFAULT NULL,
  `date3` date DEFAULT NULL,
  `date4` date DEFAULT NULL,
  PRIMARY KEY (`key1`,`key2`,`key3`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8;

INSERT INTO `test` (`key1`,`key2`,`key3`, `date1`, `date2`, `date3`, `date4`)
VALUES
	( 100, 'B', '2000-01-01', '2000-07-11', '2000-12-31', '2000-07-11', '2000-12-31' ),
	( 100, 'B', '2099-01-01', '2014-08-30', '2014-12-31', '2014-08-20', '2014-12-31' ),
	
	( 400, 'B', '2000-05-01', '2000-07-18', '2000-07-18', '2000-07-18', '2000-07-18' ),
	( 400, 'B', '2099-05-04', '2014-10-18', '2014-11-25', '2014-09-18', '2014-09-30' );

Answer Answered by Brian Evans in this comment.

While it is an error in standard SQL, which can be enabled by sql_mode=STRICT, MySQL and MariaDB allow non-aggregate columns that are not included in the GROUP BY clause.

The values that the non-aggregate columns include are completely random and not necessarily related to, as in your case, a single row with the aggregate function result.

If you rewrite the query, you'll get consistent results:

SELECT `key1`, `key2`, `key3` `date`, `date1`, `date2`, `date3`, `date4`
from test JOIN(SELECT `key1`, `key2`, MAX(`key3`) `key3` FROM `test`
GROUP BY `key1`, `key2`) `d1` USING (`key1`, `key2`, `key3`) ;
Content reproduced on this site is the property of its respective owners, and this content is not reviewed in advance by MariaDB. The views, information and opinions expressed by this content do not necessarily represent those of MariaDB or any other party.