Skip to content

Commit

Permalink
fixup! WIP: Document Microsoft.Data.Sqlite
Browse files Browse the repository at this point in the history
Transactions
  • Loading branch information
bricelam committed Dec 2, 2019
1 parent e82f7b7 commit fa8e94d
Show file tree
Hide file tree
Showing 2 changed files with 34 additions and 9 deletions.
31 changes: 26 additions & 5 deletions msdata-sqlite/transactions.md
Original file line number Diff line number Diff line change
@@ -1,11 +1,32 @@
---
title: Transactions - Microsoft.Data.Sqlite
author: bricelam
ms.date: 11/12/2019
ms.date: 12/2/2019
---
# Transactions

<!-- TODO: Write this -->
<!-- TODO: Atomic, perf -->
<!-- TODO: Isolation levels, shared cache -->
<!-- TODO: DirtyRead example -->
Transactions let you group multiple SQL statements into a single unit of work that is committed to the database as one atomic unit. If any statement in the transaction fails, changes made by the previous statements can be rolled back preserving the initial state of the database when the transaction was started. Using a transaction can also improve performance on SQLite when making a lot of changes to the database at once.

## Concurrency

In SQLite, only one transaction is allowed to have changes pending in the database at a time. Because of this, calls to [BeginTransaction](/dotnet/api/microsoft.data.sqlite.sqliteconnection.begintransaction) and the Execute methods on [SqliteCommand](/dotnet/api/microsoft.data.sqlite.sqlitecommand) may time out if another transaction takes too long to complete.

See [Database Errors](errors.md) for additional details about locking, retries, and timeouts.

## Isolation levels

Transactions are **serializable** by default in SQLite. This isolation level guarantees that any changes made within a transaction are completely isolated. Other statements executed during this transaction will not be affected by its changes.

SQLite also supports **read uncommitted** when using a shared cache. This level allows dirty reads, non-repeatable reads, and phantoms.

A *dirty read* occurs when changes pending in one transaction are returned by a query outside of the transaction, but the changes in the transaction is rolled back. The results contain data that was never actually committed to the database.

A *nonrepeatable read* occurs when a transaction queries same row twice, but the results are different because it was changed between the two queries by another transaction.

*Phantoms* are rows that get changed or added to meet the where clause of a query during a transaction. If allowed, the same query could return a different rows when executed twice in the same transaction.

Microsoft.Data.Sqlite treats the IsolationLevel passed to [BeginTransaction](/dotnet/api/microsoft.data.sqlite.sqliteconnection.begintransaction) as a minimum level. The actual isolation level will be promoted to either read uncommitted or serializable.

The following code simulates a dirty read. Note, the connection string must include `Cache=Shared`.

[!code-csharp[](../samples/msdata-sqlite/DirtyReadSample/Program.cs?name=snippet_DirtyRead)]
12 changes: 8 additions & 4 deletions samples/msdata-sqlite/DirtyReadSample/Program.cs
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,9 @@ static void Main()
var firstConnection = new SqliteConnection(connectionString);
firstConnection.Open();

var secondConnection = new SqliteConnection(connectionString);
secondConnection.Open();

var createCommand = firstConnection.CreateCommand();
createCommand.CommandText =
@"
Expand All @@ -26,7 +29,8 @@ INSERT INTO data
";
createCommand.ExecuteNonQuery();

using (firstConnection.BeginTransaction())
#region snippet_DirtyRead
using (var firstTransaction = firstConnection.BeginTransaction())
{
var updateCommand = firstConnection.CreateCommand();
updateCommand.CommandText =
Expand All @@ -36,9 +40,6 @@ UPDATE data
";
updateCommand.ExecuteNonQuery();

var secondConnection = new SqliteConnection(connectionString);
secondConnection.Open();

// Without ReadUncommitted, the command will time out since the table is locked
// while the transaction on the first connection is active
using (secondConnection.BeginTransaction(IsolationLevel.ReadUncommitted))
Expand All @@ -52,7 +53,10 @@ FROM data
var value = (string)queryCommand.ExecuteScalar();
Console.WriteLine($"Value: {value}");
}

firstTransaction.Rollback();
}
#endregion
}
}
}

0 comments on commit fa8e94d

Please sign in to comment.