fix: resolve MySQL Error 1093 when deleting users from boards

Fixes #7125 and #7069 by implementing a two-step deletion process
that avoids MySQL's restriction on deleting from a table while
selecting from it in a subquery.

The fix separates the SELECT and DELETE operations:
1. First query: Get card IDs for assignments to delete
2. Second query: Delete assignments using the collected IDs

This approach works on all supported database systems (MySQL 5.7+,
MySQL 8.0+, MariaDB 10.x+) and follows MySQL's official best practices
for handling Error 1093: 'You can't specify target table for update in FROM clause'.

The issue occurred because the original deleteByParticipantOnBoard method
used a subquery that referenced the same table being deleted from,
which MySQL prohibits but MariaDB allows (explaining why it worked
in development but failed in production).

Signed-off-by: Arne Bartelt <arne.bartelt@gmail.com>
Signed-off-by: Arne Bartelt <Arne.Bartelt@gmail.com>
This commit is contained in:
Arne Bartelt
2025-09-10 16:39:51 +02:00
parent 516294ee23
commit bffa4d0925
2 changed files with 23 additions and 7 deletions

View File

@@ -6,6 +6,7 @@
- Adrian Missy <adrian.missy@onewavestudios.com>
- Alexandru Puiu <alexpuiu20@yahoo.com>
- Arne Bartelt <arne.bartelt@gmail.com>
- Chandi Langecker <git@chandi.it>
- Christoph Wurst <christoph@winzerhof-wurst.at>
- Gary Kim <gary@garykim.dev>

View File

@@ -77,18 +77,33 @@ class AssignmentMapper extends DeckMapper implements IPermissionMapper {
}
public function deleteByParticipantOnBoard(string $participant, int $boardId, $type = Assignment::TYPE_USER) {
$qb = $this->db->getQueryBuilder();
// Step 1: Get all card IDs for the board that have assignments for this participant
// This avoids MySQL Error 1093 by separating the SELECT from the DELETE operation
$cardIdQuery = $this->db->getQueryBuilder();
$cardIdQuery->select('a.card_id')
->from('deck_assigned_users', 'a')
->innerJoin('a', 'deck_cards', 'c', 'c.id = a.card_id')
->innerJoin('c', 'deck_stacks', 's', 's.id = c.stack_id')
->where($cardIdQuery->expr()->eq('a.participant', $qb->createNamedParameter($participant, IQueryBuilder::PARAM_STR)))
->andWhere($cardIdQuery->expr()->eq('s.board_id', $qb->createNamedParameter($boardId, IQueryBuilder::PARAM_INT)))
->andWhere($cardIdQuery->expr()->eq('a.type', $qb->createNamedParameter($type, IQueryBuilder::PARAM_INT)));
$qb->delete('deck_assigned_users')
->where($qb->expr()->in('card_id', $qb->createFunction($cardIdQuery->getSQL()), IQueryBuilder::PARAM_INT_ARRAY));
$qb->executeStatement();
->where($cardIdQuery->expr()->eq('a.participant', $cardIdQuery->createNamedParameter($participant, IQueryBuilder::PARAM_STR)))
->andWhere($cardIdQuery->expr()->eq('s.board_id', $cardIdQuery->createNamedParameter($boardId, IQueryBuilder::PARAM_INT)))
->andWhere($cardIdQuery->expr()->eq('a.type', $cardIdQuery->createNamedParameter($type, IQueryBuilder::PARAM_INT)));
$result = $cardIdQuery->executeQuery();
$cardIds = [];
while ($row = $result->fetch()) {
$cardIds[] = $row['card_id'];
}
$result->closeCursor();
// Step 2: If we have card IDs, delete the assignments
if (!empty($cardIds)) {
$deleteQuery = $this->db->getQueryBuilder();
$deleteQuery->delete('deck_assigned_users')
->where($deleteQuery->expr()->eq('participant', $deleteQuery->createNamedParameter($participant, IQueryBuilder::PARAM_STR)))
->andWhere($deleteQuery->expr()->eq('type', $deleteQuery->createNamedParameter($type, IQueryBuilder::PARAM_INT)))
->andWhere($deleteQuery->expr()->in('card_id', $deleteQuery->createNamedParameter($cardIds, IQueryBuilder::PARAM_INT_ARRAY)));
$deleteQuery->executeStatement();
}
}