Open
Description
Bug description
In EF Core 8, queries using DefaultIfEmpty()
on value types were automatically translated to include a COALESCE
function in the generated SQL:
// LINQ query
from account in dbContext.Accounts
from balance in account.Transactions
.Where(x => x.AccountId > 500)
.Take(1)
.OrderBy(x => true)
.Select(x => x.Balance)
.DefaultIfEmpty()
select balance;
-- EF Core 8 SQL translation
SELECT COALESCE([t0].[Balance], 0.0)
FROM [Accounts] AS [a]
OUTER APPLY (
SELECT TOP(1) [t].[Balance]
FROM [Transactions] AS [t]
WHERE [a].[AccountId] = [t].[AccountId] AND [t].[AccountId] > 500
) AS [t0]
In EF Core 9, this translation behavior has changed. The COALESCE is no longer applied:
-- EF Core 9 SQL translation
SELECT [t0].[Balance]
FROM [Accounts] AS [a]
OUTER APPLY (
SELECT TOP(1) [t].[Balance]
FROM [Transactions] AS [t]
WHERE [a].[AccountId] = [t].[AccountId] AND [t].[AccountId] > 500
) AS [t0]
Without the COALESCE, NULL values can be returned, causing InvalidOperationException: Nullable object must have a value when materializing to non-nullable types.
The workaround is to explicitly handle nullability in the LINQ query by casting to a nullable type and using the null-coalescing operator:
from account in dbContext.Accounts
from balance in account.Transactions
.Where(x => x.AccountId > 500)
.Take(1)
.OrderBy(x => true)
.Select(x => (decimal?)x.Balance) // Cast to nullable
.DefaultIfEmpty()
select balance ?? 0m; // Handle null
Your code
using Microsoft.EntityFrameworkCore;
using Microsoft.Extensions.Logging;
using System.ComponentModel.DataAnnotations.Schema;
using System.Text.Json;
using var dbContext = new PlayGroundEfCoreContext();
dbContext.Database.EnsureCreated();
/*
dbContext.Add(new Account()
{
Transactions = new List<Transaction>()
{
new Transaction()
{
Balance = 100
}
}
});
dbContext.SaveChanges();
*/
var balances = (
from account in dbContext.Accounts
from balance in account.Transactions
.Where(x => x.AccountId > 500)
.Take(1)
.OrderBy(x => true)
.Select(x => x.Balance)
.DefaultIfEmpty()
select balance).ToList();
Console.WriteLine(JsonSerializer.Serialize(balances));
public class PlayGroundEfCoreContext : DbContext
{
public DbSet<Account> Accounts { get; set; }
public DbSet<Transaction> Transactions { get; set; }
protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder)
{
optionsBuilder
.UseSqlite("Data Source=test.db")
.LogTo(Console.WriteLine, LogLevel.Information)
.EnableSensitiveDataLogging();
}
protected override void OnModelCreating(ModelBuilder modelBuilder)
{
modelBuilder.Entity<Account>()
.HasMany(a => a.Transactions)
.WithOne(t => t.Account)
.HasForeignKey(t => t.AccountId);
}
}
[Table("Accounts")]
public class Account
{
public int AccountId { get; set; }
public ICollection<Transaction> Transactions { get; set; }
}
[Table("Transactions")]
public class Transaction
{
public int TransactionId { get; set; }
public int AccountId { get; set; }
public decimal Balance { get; set; }
public Account Account { get; set; }
}
Stack traces
System.InvalidOperationException
HResult=0x80131509
Message=Nullable object must have a value.
Source=System.Private.CoreLib
StackTrace:
at System.ThrowHelper.ThrowInvalidOperationException_InvalidOperation_NoValue()
at Microsoft.EntityFrameworkCore.Query.Internal.SingleQueryingEnumerable`1.Enumerator.MoveNext()
at System.Collections.Generic.List`1..ctor(IEnumerable`1 collection)
at System.Linq.Enumerable.ToList[TSource](IEnumerable`1 source)
at Program.<<Main>$>d__0.MoveNext() in
Verbose output
EF Core version
9.0.4
Database provider
SqlServer & Sqlite
Target framework
No response
Operating system
No response
IDE
No response