Skip to content

Instantly share code, notes, and snippets.

@jotbe
Created July 6, 2011 10:35
Show Gist options
  • Save jotbe/1066973 to your computer and use it in GitHub Desktop.
Save jotbe/1066973 to your computer and use it in GitHub Desktop.
MySQL: Get formatted ISO date from string with european date (can be easily extended to other formats)
/**
* This script has been tested in MySQL 5.1.37.
* It might work with other SQL-DBMS as well.
*/
DROP FUNCTION IF EXISTS getSqlDate;
DELIMITER //
CREATE FUNCTION getSqlDate(str VARCHAR(10))
RETURNS VARCHAR(10) DETERMINISTIC
CASE
WHEN (str REGEXP '^[0-3][0-9]\.[01][0-9]\.[0-9]{4}$') THEN
/* European: 01.06.2011 */
RETURN STR_TO_DATE(str, GET_FORMAT(DATE, 'EUR'));
WHEN (str REGEXP '^[0-9]{4}-[01][0-9]-[0-3][0-9]$') THEN
/* ISO 8601: 2011-06-01 */
RETURN str;
ELSE
RETURN 'ERR';
END CASE;
//
DELIMITER ;
SELECT
@eur := '01.01.2011' eur_date,
@iso := '2011-01-01' iso_date,
STR_TO_DATE(@eur, GET_FORMAT(DATE, 'EUR')) eur_str2date,
STR_TO_DATE(@iso, GET_FORMAT(DATE, 'ISO')) iso_str2date,
(@eur REGEXP '^[0-3][0-9]\.[01][0-9]\.20[0-9]{2}$') eur_valid_date,
(@iso REGEXP '^20[0-9]{2}-[01][0-9]-[0-3][0-9]$') iso_valid_date,
@date := @eur test_date,
getSqlDate(@date) test_date_out;
/**
* Output:
* +------------+------------+--------------+--------------+----------------+----------------+------------+---------------+
* | eur_date | iso_date | eur_str2date | iso_str2date | eur_valid_date | iso_valid_date | test_date | test_date_out |
* +------------+------------+--------------+--------------+----------------+----------------+------------+---------------+
* | 01.01.2011 | 2011-01-01 | 2011-01-01 | 2011-01-01 | 1 | 1 | 01.01.2011 | 2011-01-01 |
* +------------+------------+--------------+--------------+----------------+----------------+------------+---------------+
*/
@md2perpe
Copy link

md2perpe commented Jul 7, 2011

The multitude of date formats really is a big mess. You never know in what order the parts come, although sometimes you can guess.

I prefer the ISO format. Not only is it the standard here in Sweden, but it's also makes dates sortable as strings.

By the way... Is your code written for some particular database server/engine (e.g. MySQL)?

@jotbe
Copy link
Author

jotbe commented Jul 7, 2011

I agree with you. The code is written and tested in MySQL - thanks for asking. I've just added the info to the gist.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment