Skip to content

Conversation

@juliusknorr
Copy link
Member

@juliusknorr juliusknorr commented Jul 17, 2023

It seems that MySQL is badly optimizing DELETE FROM .. WHERE IN with subqueries as in that a full table scan and row locks are done when the subquery returns no result. In most cases we have a document id so we can apply it to the delete query itself to reduce the amount of rows to scan.

Before

MariaDB [oc]> EXPLAIN DELETE FROM `oc_text_sessions` WHERE `id` IN (SELECT `s`.`id` FROM `oc_text_sessions` `s` LEFT JOIN `oc_text_steps` `st` ON `st`.`session_id` = `s`.`id` WHERE (`last_contact` < '1689576710') AND (`st`.`id` IS NULL)
AND (`s`.`document_id` = '7197220'));
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+
| id   | select_type        | table            | type  | possible_keys                               | key                  | key_len | ref     | rows | Extra                                |
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+
|    1 | PRIMARY            | oc_text_sessions | ALL   | NULL                                        | NULL                 | NULL    | NULL    | 1364 | Using where                          |
|    2 | DEPENDENT SUBQUERY | s                | range | PRIMARY,ts_docid_lastcontact,ts_lastcontact | ts_docid_lastcontact | 16      | NULL    | 1    | Using where; Using index             |
|    2 | DEPENDENT SUBQUERY | st               | ref   | ts_session                                  | ts_session           | 8       | oc.s.id | 3    | Using where; Using index; Not exists |
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+

After

MariaDB [oc]> EXPLAIN DELETE FROM `oc_text_sessions` WHERE document_id = '7197220' AND `id` IN (SELECT `s`.`id` FROM `oc_text_sessions` `s` LEFT JOIN `oc_text_steps` `st` ON `st`.`session_id` = `s`.`id` WHERE (`last_contact` < '168957671
0') AND (`st`.`id` IS NULL)
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+
| id   | select_type        | table            | type  | possible_keys                               | key                  | key_len | ref     | rows | Extra                                |
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+
|    1 | PRIMARY            | oc_text_sessions | range | ts_docid_lastcontact                        | ts_docid_lastcontact | 8       | NULL    | 4    | Using where                          |
|    2 | DEPENDENT SUBQUERY | s                | range | PRIMARY,ts_docid_lastcontact,ts_lastcontact | ts_docid_lastcontact | 16      | NULL    | 1    | Using where; Using index             |
|    2 | DEPENDENT SUBQUERY | st               | ref   | ts_session                                  | ts_session           | 8       | oc.s.id | 3    | Using where; Using index; Not exists |
+------+--------------------+------------------+-------+---------------------------------------------+----------------------+---------+---------+------+--------------------------------------+

Signed-off-by: Julius Härtl <jus@bitgrid.net>
@juliusknorr juliusknorr added bug Something isn't working 3. to review labels Jul 17, 2023
@cypress
Copy link

cypress bot commented Jul 17, 2023

1 flaky tests on run #11137 ↗︎

0 149 2 0 Flakiness 1

Details:

fix: Use prefilter for delete with subquery
Project: Text Commit: 5e9259812a
Status: Passed Duration: 03:38 💡
Started: Jul 17, 2023 7:42 AM Ended: Jul 17, 2023 7:45 AM
Flakiness  cypress/e2e/nodes/HardBreak.spec.js • 1 flaky test

View Output Video

Test Artifacts
Hard break support > Can create hard breaks with shift+enter Output Screenshots

This comment has been generated by cypress-bot as a result of this project's GitHub integration settings.

@juliusknorr juliusknorr merged commit 69e536d into main Jul 17, 2023
@juliusknorr juliusknorr deleted the bugfix/noid/prevent-delete-deadlock branch July 17, 2023 08:34
@juliusknorr
Copy link
Member Author

Let me cherry pick this to the existing backports of #4521

juliusknorr added a commit that referenced this pull request Jul 19, 2023
reverts #4339 and #4539 except for the added tests and moves to plain
PHP chunking to avoid issues with MySQL 8

Signed-off-by: Julius Härtl <jus@bitgrid.net>
juliusknorr added a commit that referenced this pull request Jul 19, 2023
reverts #4339 and #4539 except for the added tests and moves to plain
PHP chunking to avoid issues with MySQL 8

Signed-off-by: Julius Härtl <jus@bitgrid.net>
juliusknorr added a commit that referenced this pull request Jul 19, 2023
reverts #4339 and #4539 except for the added tests and moves to plain
PHP chunking to avoid issues with MySQL 8

Signed-off-by: Julius Härtl <jus@bitgrid.net>
backportbot-nextcloud bot pushed a commit that referenced this pull request Jul 19, 2023
reverts #4339 and #4539 except for the added tests and moves to plain
PHP chunking to avoid issues with MySQL 8

Signed-off-by: Julius Härtl <jus@bitgrid.net>
backportbot-nextcloud bot pushed a commit that referenced this pull request Jul 19, 2023
reverts #4339 and #4539 except for the added tests and moves to plain
PHP chunking to avoid issues with MySQL 8

Signed-off-by: Julius Härtl <jus@bitgrid.net>
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

3. to review bug Something isn't working

Projects

None yet

Development

Successfully merging this pull request may close these issues.

3 participants