MySQL select rows between months

Let’s say you want all rows from a table that have a date between next month and the next 3 months, MySQL provide us (since 4.1) a beautiful LAST_DAY function (for the record there is no FIRST_DAY…. at least yet), and the DATE_ADD function (actually there is also a DATE_SUB).

Getting first day of next month:

SELECT DATE_ADD(LAST_DAY(NOW()), INTERVAL 1 DAY);

Getting the last day of the next third calendar month

SELECT LAST_DAY(DATE_ADD(NOW(), INTERVAL 3 MONTH));

So, from here is pretty simple:

SELECT * FROM table WHERE 
date_field > DATE_ADD(LAST_DAY(NOW()), INTERVAL 1 DAY) AND 
date_field < LAST_DAY(DATE_ADD(NOW(), INTERVAL 3 MONTH));

Bonus query:

get first day of current month

SELECT CAST(DATE_FORMAT(NOW() ,'%Y-%m-01') as DATE)

Mysql split column string into rows

A MySQL recipe, that you can use to split a cell value by a known separator into different rows, in some way similar to the PHP explode function or split in PERL.

To turn this:

id value
1 4,5,7
2 4,5
3 4,5,6
…. ….

Into this

id value
1 4
1 5
1 7
2 4
2 5
3 4
3 5
3 6
…. ….

You can simply write and call a stored procedure

DELIMITER $$

DROP PROCEDURE IF EXISTS explode_table $$
CREATE PROCEDURE explode_table(bound VARCHAR(255))

  BEGIN

    DECLARE id INT DEFAULT 0;
    DECLARE value TEXT;
    DECLARE occurance INT DEFAULT 0;
    DECLARE i INT DEFAULT 0;
    DECLARE splitted_value INT;
    DECLARE done INT DEFAULT 0;
    DECLARE cur1 CURSOR FOR SELECT table1.id, table1.value
                                         FROM table1
                                         WHERE table1.value != '';
    DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = 1;

    DROP TEMPORARY TABLE IF EXISTS table2;
    CREATE TEMPORARY TABLE table2(
    `id` INT NOT NULL,
    `value` VARCHAR(255) NOT NULL
    ) ENGINE=Memory;

    OPEN cur1;
      read_loop: LOOP
        FETCH cur1 INTO id, value;
        IF done THEN
          LEAVE read_loop;
        END IF;

        SET occurance = (SELECT LENGTH(value)
                                 - LENGTH(REPLACE(value, bound, ''))
                                 +1);
        SET i=1;
        WHILE i <= occurance DO
          SET splitted_value =
          (SELECT REPLACE(SUBSTRING(SUBSTRING_INDEX(value, bound, i),
          LENGTH(SUBSTRING_INDEX(value, bound, i - 1)) + 1), ',', ''));

          INSERT INTO table2 VALUES (id, splitted_value);
          SET i = i + 1;

        END WHILE;
      END LOOP;

      SELECT * FROM table2;
    CLOSE cur1;
  END; $$

Then you simply call it

CALL explode_table(',');
There it is the bare bones. From here it’s simple to adapt and build to your own needs, like adding some kind of filter parameter, order, etc… if your main interface to Mysql is PHPMyAdmin (as of now) forget it, its rubish with this procedures queries, you can use own MySQL GUI – MySQL Workbench – to interface with, or rely on the old CLI ‘mysql’ command, just put the stored procedure definition in a file and load it with a redirect:

mysql -u username -p -D databasename < procedure_definition_file.txt

Also remember:

  • if backups are made with mysqldump, use the –routines switch so the stored procedure definition goes in the dumps.
  • works mysql >= 5.0 only
  • performance, normalization and concurrency – this is not the correct way to do a many to many relationship with a RDBS, you should use a relationship table, and joins to work with it.
  • OK, so your project manager/marketing/boss changed the game rules at the very last moment, and to implement it correctly you must rework a lot of code, i understand 🙂 but even then enter this road at your own peril.