-
Notifications
You must be signed in to change notification settings - Fork 1.3k
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
sqlite: fix inconsistent read-after-write #3354
sqlite: fix inconsistent read-after-write #3354
Conversation
while let Some(res) = stream.try_next().await? { | ||
if let Either::Right(row) = res { | ||
return Ok(Some(row)); | ||
out = Ok(Some(row)); |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
The reason it doesn't work this way is because we didn't want the application to have to wait for the full result set before returning. For example, if someone forgot a LIMIT 1
on their query and was doing a SELECT ... ORDER BY ...
to get the first/last item in an ordered set, the call would have to churn through the whole dataset before returning.
The bug happens because of a race condition: the worker sends the row data and then continues calling sqlite3_step()
and only stops when it notices the result channel is closed, then it calls sqlite3_reset()
which is supposed to actually commit the changes. In the meantime, the application receives the row and then continues to the next query, which it executes on another connection which may not be able to see the changes yet.
In reality, this needs to be handled proactively by the driver. The message to the worker should specify that it's only expecting one row, and then the worker should step until it gets the row and immediately call sqlite3_reset()
(by dropping ExecuteIter
) before returning it. That should fix the race condition.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
That makes sense, thanks @abonander. Does the approach in 02ca0ed look a little bit closer to what you had in mind? I don't know the project's naming/organization conventions so apologies for that.
@abonander I added a commit which changes the approach slightly to account for a test failure I saw in CI, where the test |
sqlx-sqlite/src/connection/mod.rs
Outdated
pub(crate) enum Returning { | ||
Many, | ||
One, | ||
} |
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
You don't need a bespoke enum. I would just take a limit: Option<usize>
parameter and stop reading rows when the limit is reached. For .fetch_optional()
, you'd pass Some(1)
.
There was a problem hiding this comment.
Choose a reason for hiding this comment
The reason will be displayed to describe this comment to others. Learn more.
@abonander good call, updated.
This comment has been minimized.
This comment has been minimized.
@CommanderStorm Added. |
@ckampfe if you rebase it should fix CI. |
5c0f958
to
b95a256
Compare
@abonander done! |
Hey @abonander and @CommanderStorm, thank you for working with me on this PR, I appreciate it and all the work you do on this project. |
* sqlite: fix inconsistent read-after-write fetch_one/fetch_optional * try pushing fetch_optional early-return into worker * run cargo fmt * fix "it_can_execute_multiple_statements" test failure * use Option<usize> instead of bespoke enum for rows returned
* sqlite: fix inconsistent read-after-write fetch_one/fetch_optional * try pushing fetch_optional early-return into worker * run cargo fmt * fix "it_can_execute_multiple_statements" test failure * use Option<usize> instead of bespoke enum for rows returned
Fixes #3120
As far as I can tell, this fixes #2099 (and I think #3120, which appears to be the same)
My minimal reproduction looks like this (which is adapted from the example in #2099):
I can pretty easily get this code to panic on the
main
branch, just by running it a few times. It doesn't panic every time, as other issue reporters have noted, but it's consistent enough to notice.With this fix, I can't get it to panic at all.
The fix in this PR works by forcing the stream here to run until completion, rather than returning early in the case that it returns rows (i.e., via a
RETURNING
in SQL).As far as I can tell, this is related to how
step
insqlx-sqlite/src/statement/handle.rs
works:where the
SQLITE_ROW => return Ok(true),
clause is causing theExecuteIter
to terminate early, before SQLite can returnSQLITE_DONE
, which I believe in turn means SQLite itself may not be committing the transaction: https://github.com/launchbadge/sqlx/blob/main/sqlx-sqlite/src/connection/execute.rs#L96This
SQLITE_ROW
then causes this whole stream to terminate early, as it simply returns when it matches anEither::Right(row)
rather than anEither::Left(SqliteQueryResult)
: https://github.com/launchbadge/sqlx/blob/main/sqlx-sqlite/src/connection/executor.rs#L68-L70I think this is what is happening, and I think this PR fixes it, but please let me know if my understanding is incorrect.
Thanks!