-
-
Save emesterhazy/8519fe7d795a10cca9f530115abc972a to your computer and use it in GitHub Desktop.
MYSQL: Generate Calendar Table
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- Creates a calendar table in mysql | |
DROP TABLE IF EXISTS calendar; | |
CREATE TABLE calendar ( | |
id INTEGER PRIMARY KEY, -- year*10000+month*100+day | |
db_date DATE NOT NULL, | |
year INTEGER NOT NULL, | |
month INTEGER NOT NULL, -- 1 to 12 | |
day INTEGER NOT NULL, -- 1 to 31 | |
quarter INTEGER NOT NULL, -- 1 to 4 | |
week INTEGER NOT NULL, -- 1 to 52/53 | |
day_name VARCHAR(9) NOT NULL, -- 'Monday', 'Tuesday'... | |
month_name VARCHAR(9) NOT NULL, -- 'January', 'February'... | |
holiday_flag TINYINT(1) DEFAULT 0 CHECK (holiday_flag in (1, 0)), | |
weekend_flag TINYINT(1) DEFAULT 0 CHECK (weekday_flag in (1, 0)), | |
event VARCHAR(50), | |
UNIQUE td_ymd_idx (year,month,day), | |
UNIQUE td_dbdate_idx (db_date) | |
) Engine=innodb; | |
DROP PROCEDURE IF EXISTS fill_date_dimension; | |
DELIMITER // | |
CREATE PROCEDURE fill_date_dimension(IN startdate DATE,IN stopdate DATE) | |
BEGIN | |
DECLARE currentdate DATE; | |
SET currentdate = startdate; | |
WHILE currentdate < stopdate DO | |
INSERT INTO calendar VALUES ( | |
YEAR(currentdate)*10000+MONTH(currentdate)*100 + DAY(currentdate), | |
currentdate, | |
YEAR(currentdate), | |
MONTH(currentdate), | |
DAY(currentdate), | |
QUARTER(currentdate), | |
WEEKOFYEAR(currentdate), | |
DATE_FORMAT(currentdate,'%W'), | |
DATE_FORMAT(currentdate,'%M'), | |
0, | |
CASE DAYOFWEEK(currentdate) WHEN 1 THEN 1 WHEN 7 then 1 ELSE 0 END, | |
NULL); | |
SET currentdate = ADDDATE(currentdate,INTERVAL 1 DAY); | |
END WHILE; | |
END | |
// | |
DELIMITER ; | |
TRUNCATE TABLE calendar; | |
CALL fill_date_dimension('1900-01-01','2200-01-01'); | |
DROP PROCEDURE IF EXISTS fill_date_dimension; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment