Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add a correct composite INDEX for the history table #686

Merged
merged 2 commits into from Apr 8, 2024

Conversation

yhabteab
Copy link
Member

No complaints with PostgreSQL so far, but to maintain the consistency with MySQL/MariaDB, the index for pgsql has also been adjusted. The output of the explain command also shows the differences between before and after this change.

PostgreSQL (EXPLAIN)

Before:

icingadb=# EXPLAIN SELECT * FROM history ORDER BY event_time, event_type LIMIT 25;
                                              QUERY PLAN                                               
-------------------------------------------------------------------------------------------------------
 Limit  (cost=0.39..7.36 rows=25 width=368)
   ->  Incremental Sort  (cost=0.39..56.14 rows=200 width=368)
         Sort Key: event_time, event_type
         Presorted Key: event_time
         ->  Index Scan using idx_history_event_time on history  (cost=0.14..47.15 rows=200 width=368)
(5 rows)

After:

icingadb=# EXPLAIN SELECT * FROM history ORDER BY event_time, event_type LIMIT 25;
                                                 QUERY PLAN                                                 
------------------------------------------------------------------------------------------------------------
 Limit  (cost=0.14..6.02 rows=25 width=368)
   ->  Index Scan using idx_history_event_time_event_type on history  (cost=0.14..47.15 rows=200 width=368)
(2 rows)

fixes #683

@cla-bot cla-bot bot added the cla/signed label Mar 11, 2024
@yhabteab yhabteab added bug Something isn't working area/schema labels Mar 11, 2024
@julianbrost
Copy link
Contributor

   ->  Incremental Sort  (cost=0.39..56.14 rows=200 width=368)

That optimization was only added PostgreSQL 13 though, so the changed index might even be useful for older versions.

@julianbrost julianbrost added this to the 1.1.2 milestone Mar 11, 2024
oxzi
oxzi previously approved these changes Mar 11, 2024
Copy link
Member

@oxzi oxzi left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I have successfully tested this PR on a local setup with round about 300k entries in the history table. LGTM.

Times with the old schema

MariaDB [icingadb]> SELECT 1 FROM history ORDER BY event_time LIMIT 1\G
*************************** 1. row ***************************
1: 1
1 row in set (0.001 sec)

MariaDB [icingadb]> SELECT 1 FROM history ORDER BY event_time, event_type LIMIT 1\G
*************************** 1. row ***************************
1: 1
1 row in set (0.260 sec)

Performing schema migration

$ time mariadb  […] icingadb < /tmp/schema-1.1.2.sql

real    0m3.122s
user    0m0.013s
sys     0m0.004s

Times with the new schema

MariaDB [icingadb]> SELECT 1 FROM history ORDER BY event_time LIMIT 1\G
*************************** 1. row ***************************
1: 1
1 row in set (0.001 sec)

MariaDB [icingadb]> SELECT 1 FROM history ORDER BY event_time, event_type LIMIT 1\G
*************************** 1. row ***************************
1: 1
1 row in set (0.001 sec)

MariaDB [icingadb]> SELECT COUNT(*) FROM history\G
*************************** 1. row ***************************
COUNT(*): 310850
1 row in set (0.169 sec)

@julianbrost
Copy link
Contributor

I noticed some strange, possibly noteworthy behavior, when testing the schema upgrade on MariaDB (11.0.2). Before I started to apply the schema change, I tried to access /icingadb/history in Icinga Web (as that's the view this index is supposed to improve). As my history table is somewhat big (21M rows), this didn't load quickly and I just left the tab open in the background. Then I sent the schema upgrade to the server, waited for a bit and wondered how long it would take.

I looked at show processlist and noticed something strange: there's a connections currently executing a SELECT statement in state "Creating sort index" whereas the ALTER TABLE ... ADD INDEX connection as well as many INSERT connections are in state "Waiting for table metadata lock":

MariaDB [icingadb]> show processlist;
+------+----------+-------------------+----------+---------+------+---------------------------------+------------------------------------------------------------------------------------------------------+----------+
| Id   | User     | Host              | db       | Command | Time | State                           | Info                                                                                                 | Progress |
+------+----------+-------------------+----------+---------+------+---------------------------------+------------------------------------------------------------------------------------------------------+----------+
|   12 | icingadb | 172.22.0.36:45694 | icingadb | Sleep   |    0 |                                 | NULL                                                                                                 |    0.000 |
| 1444 | icingadb | 172.22.0.36:41460 | icingadb | Prepare | 1215 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1458 | icingadb | 172.22.0.36:58514 | icingadb | Prepare | 1219 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1461 | icingadb | 172.22.0.36:58542 | icingadb | Prepare | 1221 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1465 | icingadb | 172.22.0.35:37240 | icingadb | Sleep   |    0 |                                 | NULL                                                                                                 |    0.000 |
| 1466 | icingadb | 172.22.0.35:37246 | icingadb | Prepare | 1217 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1467 | icingadb | 172.22.0.35:37254 | icingadb | Prepare | 1222 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1468 | icingadb | 172.22.0.36:59864 | icingadb | Sleep   |   14 |                                 | NULL                                                                                                 |    0.000 |
| 1469 | icingadb | 172.22.0.35:52672 | icingadb | Prepare | 1222 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1470 | icingadb | 172.22.0.36:46530 | icingadb | Prepare | 1217 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1474 | icingadb | 172.22.0.35:52686 | icingadb | Prepare | 1215 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1475 | icingadb | 172.22.0.36:36368 | icingadb | Prepare | 1222 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1477 | icingadb | 172.22.0.35:33222 | icingadb | Sleep   |    8 |                                 | NULL                                                                                                 |    0.000 |
| 1485 | icingadb | 172.22.0.37:44446 | icingadb | Execute | 1262 | Creating sort index             | SELECT history.id, history.environment_id, history.endpoint_id, history.object_type, history.host_id |    0.000 |
| 1494 | icingadb | localhost         | icingadb | Query   | 1224 | Waiting for table metadata lock | ALTER TABLE history ADD INDEX idx_history_event_time_event_type (event_time, event_type) COMMENT 'Hi |    0.000 |
| 1499 | icingadb | 172.22.0.35:60688 | icingadb | Prepare | 1215 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1500 | icingadb | 172.22.0.35:60704 | icingadb | Prepare | 1215 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1501 | icingadb | 172.22.0.35:60706 | icingadb | Prepare | 1214 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1502 | icingadb | 172.22.0.35:60716 | icingadb | Prepare | 1214 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1503 | icingadb | 172.22.0.35:60728 | icingadb | Prepare | 1213 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1504 | icingadb | 172.22.0.35:60742 | icingadb | Prepare | 1213 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1505 | icingadb | 172.22.0.36:44314 | icingadb | Prepare | 1213 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1506 | icingadb | 172.22.0.35:60752 | icingadb | Prepare | 1213 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1507 | icingadb | 172.22.0.36:44324 | icingadb | Prepare | 1212 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1508 | icingadb | 172.22.0.35:60764 | icingadb | Prepare | 1212 | Waiting for table metadata lock | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1510 | icingadb | 172.22.0.35:50576 | icingadb | Prepare | 1207 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1512 | icingadb | 172.22.0.36:35386 | icingadb | Prepare | 1207 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1516 | icingadb | 172.22.0.35:50582 | icingadb | Prepare | 1207 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1517 | icingadb | 172.22.0.36:35398 | icingadb | Prepare | 1207 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1518 | icingadb | 172.22.0.36:35410 | icingadb | Prepare | 1206 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1519 | icingadb | 172.22.0.36:35414 | icingadb | Prepare | 1206 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1520 | icingadb | 172.22.0.36:41900 | icingadb | Prepare | 1197 | Waiting for table metadata lock | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1521 | icingadb | 172.22.0.35:34160 | icingadb | Prepare | 1197 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1522 | icingadb | 172.22.0.36:41906 | icingadb | Prepare | 1197 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1523 | icingadb | 172.22.0.36:41918 | icingadb | Prepare | 1194 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1524 | icingadb | 172.22.0.36:41928 | icingadb | Prepare | 1184 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1525 | icingadb | 172.22.0.35:34166 | icingadb | Prepare | 1193 | Waiting for table metadata lock | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1530 | icingadb | 172.22.0.36:59066 | icingadb | Prepare | 1182 | Waiting for table metadata lock | INSERT INTO "state_history" ("endpoint_id", "id", "hard_state", "previous_hard_state", "max_check_at |    0.000 |
| 1649 | icingadb | localhost         | icingadb | Query   |    0 | starting                        | show processlist                                                                                     |    0.000 |
+------+----------+-------------------+----------+---------+------+---------------------------------+------------------------------------------------------------------------------------------------------+----------+
39 rows in set (0.001 sec)

Killing the SELECT connection unblocked everything and from then on, even the INSERT statements could run in parallel with the ALTER TABLE ... ADD INDEX (note how with each show processlist, more and more connections become idle again as they finished all the outstanding work):

MariaDB [icingadb]> kill 1485;
Query OK, 0 rows affected (0.001 sec)

MariaDB [icingadb]> show processlist;
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
| Id   | User     | Host              | db       | Command | Time | State          | Info                                                                                                 | Progress |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
|   12 | icingadb | 172.22.0.36:45694 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
| 1458 | icingadb | 172.22.0.36:58514 | icingadb | Execute |    0 | Update         | INSERT INTO "history" ("environment_id", "host_id", "service_id", "event_type", "notification_histor |    0.000 |
| 1465 | icingadb | 172.22.0.35:37240 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1466 | icingadb | 172.22.0.35:37246 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
| 1467 | icingadb | 172.22.0.35:37254 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1468 | icingadb | 172.22.0.36:59864 | icingadb | Sleep   |   45 |                | NULL                                                                                                 |    0.000 |
| 1477 | icingadb | 172.22.0.35:33222 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1494 | icingadb | localhost         | icingadb | Query   | 1255 | altering table | ALTER TABLE history ADD INDEX idx_history_event_time_event_type (event_time, event_type) COMMENT 'Hi |    0.000 |
| 1502 | icingadb | 172.22.0.35:60716 | icingadb | Execute |    0 | Update         | INSERT INTO "history" ("notification_history_id", "environment_id", "object_type", "host_id", "event |    0.000 |
| 1503 | icingadb | 172.22.0.35:60728 | icingadb | Execute |    0 | Update         | INSERT INTO "state_history" ("soft_state", "previous_soft_state", "check_attempt", "service_id", "st |    0.000 |
| 1508 | icingadb | 172.22.0.35:60764 | icingadb | Execute |    0 | Commit         | INSERT INTO "history" ("id", "state_history_id", "environment_id", "endpoint_id", "object_type", "ho |    0.000 |
| 1519 | icingadb | 172.22.0.36:35414 | icingadb | Execute |    0 | Update         | INSERT INTO "notification_history" ("object_type", "host_id", "send_time", "author", "text", "endpoi |    0.000 |
| 1521 | icingadb | 172.22.0.35:34160 | icingadb | Execute |    1 | Update         | INSERT INTO "notification_history" ("previous_hard_state", "text", "object_type", "notification_id", |    0.000 |
| 1523 | icingadb | 172.22.0.36:41918 | icingadb | Execute |    0 | Commit         | INSERT INTO "user_notification_history" ("notification_history_id", "user_id", "environment_id", "id |    0.000 |
| 1524 | icingadb | 172.22.0.36:41928 | icingadb | Execute |    0 | Update         | INSERT INTO "service_state" ("is_flapping", "next_check", "performance_data", "severity", "id", "hos |    0.000 |
| 1530 | icingadb | 172.22.0.36:59066 | icingadb | Execute |    0 | Update         | INSERT INTO "history" ("endpoint_id", "object_type", "service_id", "state_history_id", "environment_ |    0.000 |
| 1649 | icingadb | localhost         | icingadb | Query   |    0 | starting       | show processlist                                                                                     |    0.000 |
| 1651 | icingadb | 172.22.0.36:55346 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1652 | icingadb | 172.22.0.36:55358 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
19 rows in set (0.001 sec)

MariaDB [icingadb]> show processlist;
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
| Id   | User     | Host              | db       | Command | Time | State          | Info                                                                                                 | Progress |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
|   12 | icingadb | 172.22.0.36:45694 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1458 | icingadb | 172.22.0.36:58514 | icingadb | Sleep   |    4 |                | NULL                                                                                                 |    0.000 |
| 1465 | icingadb | 172.22.0.35:37240 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1466 | icingadb | 172.22.0.35:37246 | icingadb | Sleep   |    6 |                | NULL                                                                                                 |    0.000 |
| 1467 | icingadb | 172.22.0.35:37254 | icingadb | Sleep   |    5 |                | NULL                                                                                                 |    0.000 |
| 1468 | icingadb | 172.22.0.36:59864 | icingadb | Sleep   |   51 |                | NULL                                                                                                 |    0.000 |
| 1477 | icingadb | 172.22.0.35:33222 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1494 | icingadb | localhost         | icingadb | Query   | 1260 | altering table | ALTER TABLE history ADD INDEX idx_history_event_time_event_type (event_time, event_type) COMMENT 'Hi |    0.000 |
| 1502 | icingadb | 172.22.0.35:60716 | icingadb | Sleep   |    4 |                | NULL                                                                                                 |    0.000 |
| 1503 | icingadb | 172.22.0.35:60728 | icingadb | Execute |    2 | Update         | INSERT INTO "history" ("notification_history_id", "environment_id", "object_type", "host_id", "event |    0.000 |
| 1508 | icingadb | 172.22.0.35:60764 | icingadb | Sleep   |    3 |                | NULL                                                                                                 |    0.000 |
| 1521 | icingadb | 172.22.0.35:34160 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1523 | icingadb | 172.22.0.36:41918 | icingadb | Sleep   |    4 |                | NULL                                                                                                 |    0.000 |
| 1524 | icingadb | 172.22.0.36:41928 | icingadb | Sleep   |    4 |                | NULL                                                                                                 |    0.000 |
| 1649 | icingadb | localhost         | icingadb | Query   |    0 | starting       | show processlist                                                                                     |    0.000 |
| 1651 | icingadb | 172.22.0.36:55346 | icingadb | Sleep   |    4 |                | NULL                                                                                                 |    0.000 |
| 1652 | icingadb | 172.22.0.36:55358 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1653 | icingadb | 172.22.0.36:55362 | icingadb | Execute |    1 | Update         | INSERT INTO "history" ("environment_id", "host_id", "service_id", "event_type", "notification_histor |    0.000 |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
18 rows in set (0.002 sec)

MariaDB [icingadb]> show processlist;
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
| Id   | User     | Host              | db       | Command | Time | State          | Info                                                                                                 | Progress |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
|   12 | icingadb | 172.22.0.36:45694 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1458 | icingadb | 172.22.0.36:58514 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
| 1465 | icingadb | 172.22.0.35:37240 | icingadb | Sleep   |    0 |                | NULL                                                                                                 |    0.000 |
| 1466 | icingadb | 172.22.0.35:37246 | icingadb | Sleep   |   12 |                | NULL                                                                                                 |    0.000 |
| 1467 | icingadb | 172.22.0.35:37254 | icingadb | Sleep   |   10 |                | NULL                                                                                                 |    0.000 |
| 1468 | icingadb | 172.22.0.36:59864 | icingadb | Sleep   |   56 |                | NULL                                                                                                 |    0.000 |
| 1477 | icingadb | 172.22.0.35:33222 | icingadb | Sleep   |    5 |                | NULL                                                                                                 |    0.000 |
| 1494 | icingadb | localhost         | icingadb | Query   | 1266 | altering table | ALTER TABLE history ADD INDEX idx_history_event_time_event_type (event_time, event_type) COMMENT 'Hi |    0.000 |
| 1502 | icingadb | 172.22.0.35:60716 | icingadb | Sleep   |   10 |                | NULL                                                                                                 |    0.000 |
| 1508 | icingadb | 172.22.0.35:60764 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
| 1521 | icingadb | 172.22.0.35:34160 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
| 1523 | icingadb | 172.22.0.36:41918 | icingadb | Sleep   |   10 |                | NULL                                                                                                 |    0.000 |
| 1524 | icingadb | 172.22.0.36:41928 | icingadb | Sleep   |   10 |                | NULL                                                                                                 |    0.000 |
| 1649 | icingadb | localhost         | icingadb | Query   |    0 | starting       | show processlist                                                                                     |    0.000 |
| 1651 | icingadb | 172.22.0.36:55346 | icingadb | Sleep   |   10 |                | NULL                                                                                                 |    0.000 |
| 1652 | icingadb | 172.22.0.36:55358 | icingadb | Sleep   |    1 |                | NULL                                                                                                 |    0.000 |
+------+----------+-------------------+----------+---------+------+----------------+------------------------------------------------------------------------------------------------------+----------+
16 rows in set (0.001 sec)

So looks like there's a risk of blocking the whole database if there's some long-running query (in my case, the one that the new index is supposed to speed up). I'm not sure though if we can do anything about this apart from warning about it in the upgrade docs.

@yhabteab
Copy link
Member Author

I think it's because MySQL/MariaDB performs a filesort operation on a simple SELECT, I have no idea why that would block other queries though.

MariaDB [icingadb]> EXPLAIN select * from history order by event_time, event_type limit 25;
+------+-------------+---------+------+---------------+------+---------+------+-------+----------------+
| id   | select_type | table   | type | possible_keys | key  | key_len | ref  | rows  | Extra          |
+------+-------------+---------+------+---------------+------+---------+------+-------+----------------+
|    1 | SIMPLE      | history | ALL  | NULL          | NULL | NULL    | NULL | 18878 | Using filesort |
+------+-------------+---------+------+---------------+------+---------+------+-------+----------------+
1 row in set (0.005 sec)

MariaDB [icingadb]> EXPLAIN select * from history order by event_time limit 25;
+------+-------------+---------+-------+---------------+------------------------+---------+------+------+-------+
| id   | select_type | table   | type  | possible_keys | key                    | key_len | ref  | rows | Extra |
+------+-------------+---------+-------+---------------+------------------------+---------+------+------+-------+
|    1 | SIMPLE      | history | index | NULL          | idx_history_event_time | 8       | NULL | 25   |       |
+------+-------------+---------+-------+---------------+------------------------+---------+------+------+-------+
1 row in set (0.001 sec

@julianbrost
Copy link
Contributor

My guess for what's going on is some interaction of shared locks: Probably the SELECT holds a read lock on the metadata (if it didn't hold a lock, all the other connections wouldn't have to wait). On its own, this lock allows other queries. Maybe doing an ALTER TABLE now requests an exclusive lock which blocks all new readers as well (in an effort to guarantee that the exclusive lock is acquired at some point).

@lippserd
Copy link
Member

So looks like there's a risk of blocking the whole database if there's some long-running query (in my case, the one that the new index is supposed to speed up). I'm not sure though if we can do anything about this apart from warning about it in the upgrade docs.

I also think it's a good idea to have this written somewhere. Having the processlists documented as you did would be also good. So a user can quickly identify such a scenario and fix it.

Copy link
Contributor

@julianbrost julianbrost left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

After #656 is done (otherwise this would just add merge conflicts anyways), please do the following:

@yhabteab yhabteab force-pushed the missing-history-index branch 2 times, most recently from 6f92303 to c7897b9 Compare March 28, 2024 11:54
@yhabteab
Copy link
Member Author

After #656 is done (otherwise this would just add merge conflicts anyways)

Just like the aforementioned PR would do here! That is not an excuse for not having merged this before, which by the way has already been approved.

doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
@yhabteab yhabteab requested review from julianbrost and oxzi and removed request for julianbrost and oxzi March 28, 2024 16:12
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Show resolved Hide resolved
doc/04-Upgrading.md Outdated Show resolved Hide resolved
doc/04-Upgrading.md Show resolved Hide resolved
@julianbrost julianbrost merged commit 0a9f5f1 into main Apr 8, 2024
31 checks passed
@julianbrost julianbrost deleted the missing-history-index branch April 8, 2024 08:34
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
area/schema bug Something isn't working cla/signed
Projects
None yet
Development

Successfully merging this pull request may close these issues.

Missing index on history table
4 participants