Agent Perf report causing dialer to lock due to index issue
Posted: Tue Jul 20, 2021 8:11 am
Hi guys,
We are having an issue where pulling the agent performance report is causing massive locks on our server and the report doesn't return for say 1-2 minutes.
I have done some investigating and found that it is because MySQL is no longer selecting the correct index to use on the query. If you see below, the top one is what it should be (I have added in a USE INDEX into this query to show proper behaviour although this works by default on other dialers without the USE INDEX) and bottom is what we are now getting. Time difference for a single query is 0.015sec vs 6 sec. More importantly when this runs, it uses close to 100% (single core) CPU and stops the MySQL process from doing virtually anything else. (Though table lock time very miniscule)
Any insight into this issue, is this something that needs to be added in code or is there something else I can do?
Obviously need to look at investing in a reporting server which we will, but the indexing issue will still remain.
(Note: I have already check, repair, optimized tables).
Thanks in advance.
We are having an issue where pulling the agent performance report is causing massive locks on our server and the report doesn't return for say 1-2 minutes.
I have done some investigating and found that it is because MySQL is no longer selecting the correct index to use on the query. If you see below, the top one is what it should be (I have added in a USE INDEX into this query to show proper behaviour although this works by default on other dialers without the USE INDEX) and bottom is what we are now getting. Time difference for a single query is 0.015sec vs 6 sec. More importantly when this runs, it uses close to 100% (single core) CPU and stops the MySQL process from doing virtually anything else. (Though table lock time very miniscule)
Any insight into this issue, is this something that needs to be added in code or is there something else I can do?
Obviously need to look at investing in a reporting server which we will, but the indexing issue will still remain.
(Note: I have already check, repair, optimized tables).
Thanks in advance.
- Code: Select all
MariaDB [asterisk]> EXPLAIN SELECT full_name,vicidial_users.user,sum(pause_sec),sub_status,sum(wait_sec + talk_sec + dispo_sec), vicidial_users.user_group from vicidial_users,vicidial_agent_log USE INDEX (time_user) where event_time <= '2021-07-20 23:59:59' and event_time >= '2021-07-20 00:00:00' and sub_status='LOGIN' and vicidial_users.user=vicidial_agent_log.user and pause_sec<65000 and campaign_id IN('C0001') and vicidial_users.user_group IN('ADMIN') group by user,full_name,sub_status order by user,full_name,sub_status desc limit 100000;
+------+-------------+--------------------+--------+---------------+-----------+---------+----------------------------------+-------+---------------------------------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+------+-------------+--------------------+--------+---------------+-----------+---------+----------------------------------+-------+---------------------------------------------------------------------+
| 1 | SIMPLE | vicidial_agent_log | range | time_user | time_user | 6 | NULL | 11984 | Using index condition; Using where; Using temporary; Using filesort |
| 1 | SIMPLE | vicidial_users | eq_ref | user | user | 62 | asterisk.vicidial_agent_log.user | 1 | Using where |
+------+-------------+--------------------+--------+---------------+-----------+---------+----------------------------------+-------+---------------------------------------------------------------------+
2 rows in set (0.000 sec)
MariaDB [asterisk]> EXPLAIN SELECT full_name,vicidial_users.user,sum(pause_sec),sub_status,sum(wait_sec + talk_sec + dispo_sec), vicidial_users.user_group from vicidial_users,vicidial_agent_log where event_time <= '2021-07-20 23:59:59' and event_time >= '2021-07-20 00:00:00' and sub_status='LOGIN' and vicidial_users.user=vicidial_agent_log.user and pause_sec<65000 and campaign_id IN('C0001') and vicidial_users.user_group IN('ADMIN') group by user,full_name,sub_status order by user,full_name,sub_status desc limit 100000;
+------+-------------+--------------------+------+---------------------------+------+---------+------------------------------+------+----------------------------------------------+
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
+------+-------------+--------------------+------+---------------------------+------+---------+------------------------------+------+----------------------------------------------+
| 1 | SIMPLE | vicidial_users | ALL | user | NULL | NULL | NULL | 384 | Using where; Using temporary; Using filesort |
| 1 | SIMPLE | vicidial_agent_log | ref | user,event_time,time_user | user | 63 | asterisk.vicidial_users.user | 9543 | Using where |
+------+-------------+--------------------+------+---------------------------+------+---------+------------------------------+------+----------------------------------------------+
2 rows in set (0.000 sec)