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

fix(db): Delete recipients without sub query #9761

Merged
merged 1 commit into from
Jun 21, 2024

Conversation

ChristophWurst
Copy link
Member

@ChristophWurst ChristophWurst commented Jun 20, 2024

MySQL does not use indexes for the "dependent" subquery. It's either a bug or a missing optimization. EXPLAIN for the two queries is fine in isolation but when you DELETE with subquery neither the inner nor the outher query use an index. This causes a full table scan on very large tables.

Before

EXPLAIN DELETE FROM   `oc_mail_recipients` WHERE   `message_id` IN (     SELECT       `id`     FROM       `oc_mail_messages`     WHERE       (`mailbox_id` = 26)       AND (`uid` IN (36923, 10343))   );
+------+--------------------+--------------------+-----------------+-----------------------------------------------------------------------------------------------------------+---------+---------+------+-------+-------------+
| id   | select_type        | table              | type            | possible_keys                                                                                             | key     | key_len | ref  | rows  | Extra       |
+------+--------------------+--------------------+-----------------+-----------------------------------------------------------------------------------------------------------+---------+---------+------+-------+-------------+
|    1 | PRIMARY            | oc_mail_recipients | ALL             | NULL                                                                                                      | NULL    | NULL    | NULL | 55178 | Using where |
|    2 | DEPENDENT SUBQUERY | oc_mail_messages   | unique_subquery | PRIMARY,mail_messages_id_flags,mail_messages_id_flags2,mail_msg_thrd_root_snt_idx,mail_messages_mb_id_uid   | PRIMARY | 8       | func |     1 | Using where |
+------+--------------------+--------------------+-----------------+-----------------------------------------------------------------------------------------------------------+---------+---------+------+-------+-------------+

After

EXPLAIN SELECT `id` FROM `oc_mail_messages` WHERE (`mailbox_id` = 26) AND (`uid` IN (36926, 36924, 36923));
+------+-------------+------------------+-------+---------------------------------------------------------------------------------------------------+-------------------------+---------+------+------+--------------------------+
| id   | select_type | table            | type  | possible_keys                                                                                     | key                     | key_len | ref  | rows | Extra                    |
+------+-------------+------------------+-------+---------------------------------------------------------------------------------------------------+-------------------------+---------+------+------+--------------------------+
|    1 | SIMPLE      | oc_mail_messages | range | mail_messages_id_flags,mail_messages_id_flags2,mail_msg_thrd_root_snt_idx,mail_messages_mb_id_uid | mail_messages_mb_id_uid | 8       | NULL |    3 | Using where; Using index |
+------+-------------+------------------+-------+---------------------------------------------------------------------------------------------------+-------------------------+---------+------+------+--------------------------+
EXPLAIN DELETE FROM `oc_mail_recipients` WHERE `message_id` IN (69049, 69050, 69052);
+------+-------------+--------------------+-------+---------------------------+---------------------------+---------+------+------+-------------+
| id   | select_type | table              | type  | possible_keys             | key                       | key_len | ref  | rows | Extra       |
+------+-------------+--------------------+-------+---------------------------+---------------------------+---------+------+------+-------------+
|    1 | SIMPLE      | oc_mail_recipients | range | mail_recipient_msg_id_idx | mail_recipient_msg_id_idx | 5       | NULL |    6 | Using where |
+------+-------------+--------------------+-------+---------------------------+---------------------------+---------+------+------+-------------+

Fixes #9760

@ChristophWurst
Copy link
Member Author

ChristophWurst commented Jun 20, 2024

Does not work because Doctrine silently drops the join: doctrine/orm#10524 refactored to use SELECT+DELETE. It's not ideal but faster than the FTS.

@ChristophWurst ChristophWurst changed the title fix(db): Delete recipients with JOIN, not subquery fix(db): Delete recipients without sub query Jun 20, 2024
MySQL does not use indexes for the "dependent" subquery. It's either a
bug or a missing optimization. EXPLAIN for the two queries is fine in
isolation but when you DELETE with subquery neither the inner nor the
outher query use an index. This causes a full table scan on very large
tables.

Signed-off-by: Christoph Wurst <christoph@winzerhof-wurst.at>
@Altahrim
Copy link

Out of curiosity, have you tried something like this?

EXPLAIN
DELETE R.*
FROM oc_mail_recipients R, oc_mail_messages M
WHERE 
  R.message_id = M.id 
  AND M.mailbox_id = 26 
  AND uid IN (36923, 10343)
+------+-------------+-------+-------+-----------------------------------------------------------------------------------------------------------+---------------------------+---------+---------+------+--------------------------+
| id   | select_type | table | type  | possible_keys                                                                                             | key                       | key_len | ref     | rows | Extra                    |
+------+-------------+-------+-------+-----------------------------------------------------------------------------------------------------------+---------------------------+---------+---------+------+--------------------------+
|    1 | SIMPLE      | M     | range | PRIMARY,mail_messages_id_flags,mail_messages_id_flags2,mail_msg_thrd_root_snt_idx,mail_messages_mb_id_uid | mail_messages_mb_id_uid   | 8       | NULL    | 2    | Using where; Using index |
|    1 | SIMPLE      | R     | ref   | mail_recipient_msg_id_idx                                                                                 | mail_recipient_msg_id_idx | 5       | oc.M.id | 1    | Using where              |
+------+-------------+-------+-------+-----------------------------------------------------------------------------------------------------------+---------------------------+---------+---------+------+--------------------------+

However, I am not sure we can generate such query with DBAL…

@st3iny st3iny merged commit 0395f09 into main Jun 21, 2024
36 checks passed
@st3iny st3iny deleted the fix/db/delete-recipients-with-join branch June 21, 2024 14:43
@ChristophWurst
Copy link
Member Author

/backport to stable3.7

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Projects
None yet
Development

Successfully merging this pull request may close these issues.

Full table scan when deleting recipients
5 participants