-
Notifications
You must be signed in to change notification settings - Fork 314
Closed
Labels
Performance 📈Issues that are targeted to performance improvements.Issues that are targeted to performance improvements.
Milestone
Description
Reading a large (e.g. 5MB) string with SqlDataReader is 10 times slower than doing it synchronously (see BDN benchmark below); at the same time, it allocates much less memory. The same behavior reproduces both with CommandBehavior.Default and CommandBehavior.SequentialAccess, although I suspect there may be some interaction with the command behavior under the hood. Memory-wise, the expectation would be for SequentialAccess to use much less memory memory compared to the default command behavior - regardless of sync/async.
The tests were on run with .NET Core 3.0 on Ubuntu 19.04 against SQL Server running on localhost.
Related links:
- https://stackoverflow.com/a/28619983/640325, with interesting profiling and benchmarking on .NET Framework (from 2015) showing a very related but slightly different issue (only async + CommandBehavior.Default trigger the x10 slowdown)
- Performance issue when querying varbinary(MAX), varchar(MAX), nvarchar(MAX) or XML with Async efcore#18221, discussing this at the EF Core level.
Benchmark code:
[MemoryDiagnoser]
public class Benchmarks
{
const string ConnectionString = "...";
[Params(CommandBehavior.Default, CommandBehavior.SequentialAccess)]
public CommandBehavior Behavior { get; set; }
[GlobalSetup]
public void Setup()
{
using var conn = new SqlConnection(ConnectionString);
conn.Open();
using (var cmd = new SqlCommand("IF NOT EXISTS (SELECT * FROM sysobjects WHERE name='TextTable' AND xtype='U') CREATE TABLE [TextTable] ([Text] VARCHAR(MAX))", conn))
cmd.ExecuteNonQuery();
using (var cmd = new SqlCommand("INSERT INTO [TextTable] ([Text]) VALUES (@p)", conn))
{
cmd.Parameters.AddWithValue("p", new string('x', 1024 * 1024 * 5));
cmd.ExecuteNonQuery();
}
}
[Benchmark]
public async ValueTask<int> Async()
{
using var conn = new SqlConnection(ConnectionString);
using var cmd = new SqlCommand("SELECT [Text] FROM [TextTable]", conn);
await conn.OpenAsync();
await using var reader = await cmd.ExecuteReaderAsync(Behavior);
await reader.ReadAsync();
return (await reader.GetFieldValueAsync<string>(0)).Length;
}
[Benchmark]
public async ValueTask<int> Sync()
{
using var conn = new SqlConnection(ConnectionString);
using var cmd = new SqlCommand("SELECT [Text] FROM [TextTable]", conn);
conn.Open();
using var reader = cmd.ExecuteReader(Behavior);
reader.Read();
return reader.GetFieldValue<string>(0).Length;
}
}
Results:
BenchmarkDotNet=v0.11.5, OS=ubuntu 19.04
Intel Core i7-6700HQ CPU 2.60GHz (Skylake), 1 CPU, 8 logical and 4 physical cores
.NET Core SDK=3.0.100
[Host] : .NET Core 3.0.0 (CoreCLR 4.700.19.46205, CoreFX 4.700.19.46214), 64bit RyuJIT
DefaultJob : .NET Core 3.0.0 (CoreCLR 4.700.19.46205, CoreFX 4.700.19.46214), 64bit RyuJIT
Method | Behavior | Mean | Error | StdDev | Median | Gen 0 | Gen 1 | Gen 2 | Allocated |
---|---|---|---|---|---|---|---|---|---|
Async | Default | 839.58 ms | 43.2838 ms | 127.6233 ms | 930.22 ms | 98000.0000 | 97000.0000 | 96000.0000 | 11.31 KB |
Sync | Default | 61.07 ms | 1.0988 ms | 1.0278 ms | 60.80 ms | 333.3333 | 222.2222 | 222.2222 | 10600.7 KB |
Async | SequentialAccess | 813.80 ms | 44.3059 ms | 130.6370 ms | 767.23 ms | 127000.0000 | 126000.0000 | 125000.0000 | 11.31 KB |
Sync | SequentialAccess | 69.54 ms | 0.6815 ms | 0.6375 ms | 69.45 ms | 375.0000 | 250.0000 | 250.0000 | 10672.5 KB |
tibitoth, ajcvickers, jesperkristensen, saurabh500, mikhail-khalizev and 5 more
Metadata
Metadata
Assignees
Labels
Performance 📈Issues that are targeted to performance improvements.Issues that are targeted to performance improvements.