-
Notifications
You must be signed in to change notification settings - Fork 3.2k
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
Silent data loss when adding objects to an sqlite DB with PRAGMA journal_mode=DELETE in a multi-threaded environment. #30851
Comments
I can also trigger this with one reader and one writer.
eventually yields this exception:
In this case the exception happens because of this chain of events:
|
cc @bricelam |
This looks like an issue with SQLite itself. I'd follow up with them.
This causes EF to use both an INSERT and SELECT statement... INSERT INTO "Table0" ("Column0", "Column1")
VALUES (@p0, @p1);
SELECT "Id"
FROM "Table0"
WHERE changes() = 1 AND "rowid" = last_insert_rowid(); ...instead of an INSERT statement with a RETURNING clause. INSERT INTO "Table0" ("Column0", "Column1")
VALUES (@p0, @p1)
RETURNING "Id"; Which leads me to believe that the issue probably has something to do with a race condition in SQLite's handling of the RETURNING clause. |
I wonder if the AUTOINCREMENT feature is also playing into this--we know that RETURNING doesn't play well with triggers, and autoincrement has many of the same characteristics as a trigger. |
In addition to changing the generated SQL, using (var transaction = contextOne.Database.BeginTransaction())
{
contextOne.SaveChanges();
transaction.Commit();
} The bug no longer repros with this code. I wonder if SQLite needs an explicit transaction for this to be safe, despite it being a "single statement"? @roji? |
Ouch :/ Is this something we can also reproduce without EF, i.e. directly with Microsoft.Data.Sqlite (just to get an even more self-contained repro)? If so, I'd definitely try reporting this to the SQlite maintainers to see what they say... If it's really needed, we can see about always having the transaction there based on the provider - but this seems like it would be a pretty serious bug... |
I'l create a bug report. I can repro with Microsoft.Data.Sqlite & System.Data.SQLite. using System.Diagnostics;
using Microsoft.Data.Sqlite;
namespace collisionTest;
public class Program
{
public static string CreateDB()
{
string filePath = Path.GetTempFileName();
var connectionString = $"Data Source={filePath}";
using (var connection = new SqliteConnection(connectionString))
{
connection.Open();
using var command = connection.CreateCommand();
command.CommandText = @"
CREATE TABLE IF NOT EXISTS 'LogEvents' (
'Id' INTEGER NOT NULL,
'Message' TEXT NOT NULL
);
PRAGMA journal_mode=DELETE;
";
command.ExecuteNonQuery();
}
return connectionString;
}
public static long CountRecords(string connectionString)
{
using var connection = new SqliteConnection(connectionString);
connection.Open();
using var command = connection.CreateCommand();
command.CommandText = "Select count(*) from 'LogEvents';";
return (long) command.ExecuteScalar()!;
}
static async Task Main(string[] _)
{
var connectionString = CreateDB();
string notReturning = @$"
INSERT INTO 'LogEvents' ('ID', 'Message')
VALUES (1, 'test message');
";
string returning = @$"
INSERT INTO 'LogEvents' ('ID', 'Message')
VALUES (1, 'test message')
returning ID;
";
foreach (var statement in new string[]{notReturning, returning})
{
var startingCount = CountRecords(connectionString);
int inserts = 5000;
var stopWatch = Stopwatch.StartNew();
for (int i = 0; i < inserts; i++)
{
var taskOne = Task.Run(() =>
{
using var connection = new SqliteConnection(connectionString);
connection.Open();
using var command = connection.CreateCommand();
command.CommandText = statement;
command.ExecuteScalar();
});
var taskTwo = Task.Run(() =>
{
CountRecords(connectionString);
});
await taskOne;
await taskTwo;
}
stopWatch.Stop();
var finalCount = CountRecords(connectionString);
Debug.WriteLine($"SQL Statement: {statement}");
Debug.WriteLine($"{inserts} Inserts");
Debug.WriteLine($"{finalCount - startingCount} Records Created");
Debug.WriteLine($"Time Taken: {stopWatch.ElapsedMilliseconds}");
}
}
} The output of this is:
Interestingly the statement with the RETURNING is significantly faster than the one without, which seems wrong given it has to do more. |
Bug report in sqlite forum - https://sqlite.org/forum/forumpost/44aaf065a3 |
The SQLite team don't think this is an issue with the core SQLite Lib and are viewing this as a bug in System.Data.SQLite. See details in forum post linked above. Assuming that's true then this bug will also need to be fixed in Microsoft.Data.Sqlite. |
Ah yes, I think we also assume that we can stop stepping after a statement returns results. |
That being said, someone in the forum pointed out that the documentation for RETURNING states that all database modifications are made in the first step so the proposed fix shouldn't be needed. From https://www.sqlite.org/lang_returning.html#processing_order
|
@EdwardNickson thanks for opening the issue and managing the back-and-forths! Have you also reported this to System.Data.Sqlite by any chance? |
Yes. To clarify further: System.Data.SQLite is officially supported by the SQLite Development Team, primarily by me. The issue itself proved to be somewhat more complex than I initially thought, here is a brief summary:
Please feel free to reach out directly to me (via email or phone) if further issues are encountered. |
I can confirm the bug. I recently had in my logs that data sets were saved without any error and when I searched for some entries in my database they were not there. I have a huge data loss because of that. I just realized that my databases were set to Delete journal mode. Probably that was default setting in EF few versions ago? Those databases are pretty old and I haven't set them to Delete mode by myself. My newer databases are set to WAL. P.S: I have multiple processes writing and reading from same database. |
Any idea how many percentage of data can get lost because of the bug? Is the 4901 data set saved out of 5000 a realistic scenario or could it be even more under any circumstances? |
@freeze-out as with most concurrency bugs, I don't think anyone can answer that reliably; it also shouldn't really matter - if even one row can be silently lost, that's already pretty critical. |
Just wanted to give the management a number how much data might be lost. |
Looks like this can be mitigated in varuous ways:
|
It's a shame we can't retry these. I tried, but SQLite resets the whole statement and starts returning duplicate rows. This whole thing feels backwards to me. Why start returning "inserted" values before they've actually been inserted?? |
Hi,
I'm experiencing a data loss issue when using EF Core with sqlite in a multi threaded scenario. This bug seems to only happen if
PRAGMA journal_mode=DELETE
. I can't replicate it inWAL
mode.What's happening is that sometimes when a new object is added and
SaveChanges
is called on a context, the database insert appears to run successfully, andDatabaseGenerated
primary keys are created by the DB and set against the C# object, but when the database is later queried for that primary key the record doesn't exist. What's more, the next time an object is created and saved to the database it gets assigned the same primary key as the previous object. It's almost like it rolled-back the first transaction without throwing an exception.This issue does not exist in EF Core 6, it started in EF Core 7. We have found that adding
ReplaceService<IUpdateSqlGenerator, SqliteLegacyUpdateSqlGenerator>()
to our options builder resolves this issue, so it seems to be a bug in the newSqliteUpdateSqlGenerator
.Sample Program
This program sets up a database with
PRAGMA journal_mode=DELETE
, creates two dBContexts for one sqlite database and then adds objects to the contexts in one-off tasks which run in parallel. After each addition it checks to ensure the primary keys set in each context's call toSaveChanges
is unique. If the keys are not unique it throws an exception.What I expect to happen:
The program runs to completion with no exceptions.
What actually happens:
The program throws an exception because the objects added to the two different contexts ended up with the same primary key.
Include provider and version information
EF Core version: 7.0.5
Database provider: Microsoft.EntityFrameworkCore.Sqlite
Target framework: .NET 7.0
Operating system: Ubuntu 18.04 & Ubuntu 20.04
IDE: VS Code
The text was updated successfully, but these errors were encountered: