Skip to content

Instantly share code, notes, and snippets.

@MiniCodeMonkey
Created March 30, 2012 02:40
Show Gist options
  • Save MiniCodeMonkey/2245997 to your computer and use it in GitHub Desktop.
Save MiniCodeMonkey/2245997 to your computer and use it in GitHub Desktop.
/*
This query returns the id's of stores which are open right now.
The date field for an opening hour can be either an explicit date or a weekday, an explicit date has higher priority than a weekday, and thus overrides a weekday.
A store is considered closed the whole day if there is an explicit date set (not a weekday) and closed=1 - or - no opening_hour is registered for the store on the day
Example data:
store_id date open_time close_time closed dayandnight closes_after_midnight
---------- -------- ---------- ---------- ------- ------------ ----------------------
113243 monday 06:00:00 22:00:00 0 0 0
113243 tuesday 06:00:00 22:00:00 0 0 0
113243 wednesday 06:00:00 22:00:00 0 0 0
113243 friday 06:00:00 02:00:00 0 0 1
113243 saturday 00:01:00 23:59:00 0 1 0
113243 2012-03-12 00:00:00 00:00:00 1 0 0
Also note:
If the current time is before 04:30 (am), the date is set to yesterday's date
*/
SELECT store_id FROM opening_hours WHERE date='2012-03-30' /* First check if we can find any opening hours for todays date */
AND
(
dayandnight=1 /* Store is open day and night? */
OR
(
/* If store closes after midnight, subtract 24 hours from open_time before checking if stores is based based on hours */
(closes_after_midnight = 1 AND (SUBTIME(open_time, '24:00:00') < CURTIME() AND close_time > CURTIME()))
OR
/* If store closes before midnight, just check if current time is within open and close time */
(closes_after_midnight = 0 AND (open_time < CURTIME() AND close_time > CURTIME()))
)
) AND closed=0 /* Do not select stores which are explicitly closed */
UNION
SELECT store_id FROM opening_hours WHERE (date='friday') /* Then check if we can find any opening hours for todays weekday */
AND
(
dayandnight=1 /* Store is open day and night? */
OR
(
/* If store closes after midnight, subtract 24 hours from open_time before checking if stores is based based on hours */
(closes_after_midnight = 1 AND (SUBTIME(open_time, '24:00:00') < CURTIME() AND close_time > CURTIME()))
OR
/* If store closes before midnight, just check if current time is within open and close time */
(closes_after_midnight = 0 AND (open_time < CURTIME() AND close_time > CURTIME()))
)
)
AND store_id NOT IN ( /* DO NOT select weekday stores if we already got a match from the date. NB! This query also includes explicitly closed stores */
SELECT store_id FROM opening_hours WHERE date='2012-03-30'
AND
(
dayandnight=1 /* Store is open day and night? */
OR
(
/* If store closes after midnight, subtract 24 hours from open_time before checking if stores is based based on hours */
(closes_after_midnight = 1 AND (SUBTIME(open_time, '24:00:00') < CURTIME() AND close_time > CURTIME()))
OR
/* If store closes before midnight, just check if current time is within open and close time */
(closes_after_midnight = 0 AND (open_time < CURTIME() AND close_time > CURTIME()))
)
)
)
@MiniCodeMonkey
Copy link
Author

MiniCodeMonkey commented Apr 15, 2012 via email

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