I have the following table in MYSQL database.
CREATE TABLE IF NOT EXISTS `wp_my_default_settings` (
`ds_id` int(11) NOT NULL AUTO_INCREMENT,
`user_id` int(11) NOT NULL,
`whichday` varchar(10) NOT NULL,
`tillday` varchar(10) NOT NULL,
`start_time` varchar(10) NOT NULL,
`end_time` varchar(10) NOT NULL,
`max_no_msg` int(11) NOT NULL,
`created_date` datetime NOT NULL,
PRIMARY KEY (`ds_id`)
) ENGINE=MyISAM DEFAULT CHARSET=latin1 AUTO_INCREMENT=11 ;
--
-- Dumping data for table `wp_my_default_settings`
--
INSERT INTO `wp_my_default_settings` (`ds_id`, `user_id`, `whichday`, `tillday`, `start_time`, `end_time`, `max_no_msg`, `created_date`) VALUES
(10, 11, 'Thu', 'Fri', '11:57 PM', '01:54 PM', 22, '2015-06-05 13:56:04'),
(9, 11, 'Thu', 'Thu', '12:06 AM', '02:46 PM', 20, '2015-06-05 13:56:04'),
(8, 11, 'Wed', 'Wed', '05:11 AM', '12:47 PM', 34, '2015-06-05 13:56:04'),
(7, 11, 'Tue', 'Tue', '10:02 AM', '05:14 PM', 50, '2015-06-05 13:56:04'),
(6, 11, 'Sun', 'Sun', '06:30 PM', '06:30 PM', 40, '2015-06-05 13:56:04');
I have a time specified as Fri 7:16 AM
I want to formulate a query selecting that row which has 'Fri 7:16' BETWEEN CONCAT( CONCAT( whichday, ' ' ) , start_time ) AND CONCAT( CONCAT( tillday, ' ' ) , end_time )
My query is
SELECT `ds_id` , `whichday` , `start_time` , `tillday` ,
`end_time` , STR_TO_DATE( CONCAT( CONCAT( whichday, ' ' ) , start_time ) , '%a %h:%i %p' ) AS 'Start',
STR_TO_DATE( CONCAT( CONCAT( tillday, ' ' ) , end_time ) , '%a %h:%i %p' ) AS 'End',
STR_TO_DATE( 'Fri 07:16 AM', '%a %h:%i %p' ) AS 'Current'
FROM `wp_my_default_settings`
WHERE `user_id` = '11'
AND (
STR_TO_DATE( 'Fri 07:16 AM', '%a %h:%i %p' )
BETWEEN STR_TO_DATE( CONCAT( CONCAT( whichday, ' ' ) , start_time ) , '%a %h:%i %p' )
AND STR_TO_DATE( CONCAT( CONCAT( tillday, ' ' ) , end_time ) , '%a %h:%i %p' )
)
AND `max_no_msg` >= (
SELECT COUNT( `offer_id` )
FROM `wp_user_offers_by_adv`
WHERE `offer_user_id` = '11' )
Instead of getting row with ds_id=10
I get rows with ds_id 8
and 9
Please help
The problem is, that
STR_TO_DATE( 'Fri 07:16 AM', '%a %h:%i %p' )
results in0000-00-00 07:16:00
and this happens to all your "dates". This means you loose the day-of-the-week information.You can fix this by replacing the day of the week by a date. E.g. You can use
2015-06-01
as Monday and2015-06-07
as Sunday.But there are a lot to improve in the whole table structure.
TIME
field.This saves you about 6 bytes (or 66%) per field and can make queries easier.
Store the day-of-the-week as a number (1 to 7) in a
TINYINT
field.This saves you about 3 bytes (or 75%) and enables you to make the query like this:
No more need for
CONCAT
andSTR_TO_DATE
which means you can use indexes better.Alternative to the first two point you can store the day and the time in a
DATETIME
field, using a date, that has the right day-of-the-week. If you put all your dates in the same week (e.g. the week from 2015-06-01 to 2015-06-07) you can make queries just like