Description
Description
Every time the startpage of gitea is loading it took a very long time (>8s). We have activated the mysql-slow-query-log to inspect what is happening and there is a query which tooks a very long time:
SELECT `action`.* FROM `action` INNER JOIN `repository` ON `repository`.id = `action`.repo_id WHERE user_id=7 AND is_deleted=0 ORDER BY `action`.`created_unix` DESC LIMIT 20;
# Time: 2023-11-20T10:19:43.302946Z
# User@Host: gitea[gitea] @ [198.18.4.243] Id: 266
# Query_time: 8.203707 Lock_time: 0.000028 Rows_sent: 20 Rows_examined: 64560
After using mysql explain to analyze the query, it shows the query is not using the correct index:
mysql> explain SELECT `action`.* FROM `action` INNER JOIN `repository` ON `repository`.id = `action`.repo_id WHERE user_id=7 AND is_deleted=0 ORDER BY `action`.`created_unix` DESC LIMIT 20;
+----+-------------+------------+------------+-------+------------------+------------------------+---------+---------------------------------+------+----------+----------------------------------------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+------------+------------+-------+------------------+------------------------+---------+---------------------------------+------+----------+----------------------------------------------+
| 1 | SIMPLE | repository | NULL | index | PRIMARY | IDX_repository_is_fork | 1 | NULL | 170 | 100.00 | Using index; Using temporary; Using filesort |
| 1 | SIMPLE | action | NULL | ref | IDX_action_r_u_d | IDX_action_r_u_d | 19 | gitea.repository.id,const,const | 273 | 100.00 | NULL |
+----+-------------+------------+------------+-------+------------------+------------------------+---------+---------------------------------+------+----------+----------------------------------------------+
2 rows in set, 1 warning (0.01 sec)
For testing purpose we removed the index IDX_action_r_u_d and started the explain again:
mysql> drop index IDX_action_r_u_d on action;
Query OK, 0 rows affected (0.01 sec)
Records: 0 Duplicates: 0 Warnings: 0
mysql> explain SELECT `action`.* FROM `action` INNER JOIN `repository` ON `repository`.id = `action`.repo_id WHERE user_id=7 AND is_deleted=0 ORDER BY `action`.`created_unix` DESC LIMIT 20;
+----+-------------+------------+------------+--------+---------------+------------------+---------+----------------------+------+----------+-------------+
| id | select_type | table | partitions | type | possible_keys | key | key_len | ref | rows | filtered | Extra |
+----+-------------+------------+------------+--------+---------------+------------------+---------+----------------------+------+----------+-------------+
| 1 | SIMPLE | action | NULL | index | NULL | IDX_action_c_u_d | 19 | NULL | 20 | 1.00 | Using where |
| 1 | SIMPLE | repository | NULL | eq_ref | PRIMARY | PRIMARY | 8 | gitea.action.repo_id | 1 | 100.00 | Using index |
+----+-------------+------------+------------+--------+---------------+------------------+---------+----------------------+------+----------+-------------+
2 rows in set, 1 warning (0.01 sec)
Now the query is using the IDX_action_c_u_d and the primary index.
The query is now incredibly fast in comparison. It took
20 rows in set (0.00 sec)
Before removing the index it took 20 rows in set (8.18 sec)
.
Can you check this behaviour of the index in mysql. Maybe the removed index is needed in other situations.
The workaround of removing the index is working fine for us, but every time restarting the gitea instance, the index will be created again.
Gitea Version
1.20.5
Can you reproduce the bug on the Gitea demo site?
No
Log Gist
No response
Screenshots
No response
Git Version
2.40.1
Operating System
Debian 11
How are you running Gitea?
It is running in the official docker container.
The following images are used:
image: gitea:1.20.5
image: mysql:5.7
image: gitea-runner
Database
MySQL/MariaDB