Re: Find free appointments faster
Hi Bingo,
My guess is that your biggest problem is the subquery on appointments. The main issues that prevents are more optimal plan is:
1. Use of expressions that prevents use of indexes.
2. OR expressions is not easily optimized
For the first problem: You should rewrite
DATE(appointments.appointment_start)=@running_date
to
appointments.appointment_start
BETWEEN DATE_ADD(@running_date, INTERVAL 0 HOUR)
AND DATE_ADD(@running_date, INTERVAL 24 HOUR)
This should make it possible to use all columns of the consultant_room_appointment index.
And do you really need to add 1 second?
BETWEEN ... AND expressions include the end values.
For the second problem, instead of doing
WHERE x < (SELECT COUNT(*) ... WHERE a OR b)
you can do
WHERE x < (SELECT COUNT(*) ... WHERE a) + (SELECT COUNT(*) ... WHERE b)
For this to help in your case, I would think you will need to store date and time in separate columns, so that the testing on @running_date becomes an equality, you would need to drop the adding of seconds, and you would need indexes on both (consultant, room, date, start) and (consultant, room, date, end)
Another advice: With InnoDB you should define the PRIMARY KEY when creating the table. Otherwise, InnoDB will add a hidden primary key.
Øystein Grøvlen,
Senior Principal Software Engineer,
MySQL Group, Oracle,
Trondheim, Norway
Subject
Views
Written By
Posted
3803
November 08, 2017 12:32AM
770
November 08, 2017 12:48AM
Re: Find free appointments faster
786
November 08, 2017 04:57AM
804
November 08, 2017 10:43PM
780
November 08, 2017 11:31PM
708
November 09, 2017 09:27AM
740
November 14, 2017 10:19AM
716
November 14, 2017 09:31AM
789
November 08, 2017 11:22PM