-
Notifications
You must be signed in to change notification settings - Fork 3.3k
Condition's order will cause different result when using .Contains() to search string cross varchar and nvarchar columns #29646
New issue
Have a question about this project? # for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “#”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? # to your account
Comments
Duplicate of #19503 |
This has already been fixed for the recently-released EF Core 7.0, please give that a try. |
@roji Another new information from my partner, he found out cause my value in nvarchar column is Chinese base, if I change db's collation to |
Confirmed that there's a bug here. Minimal repro: await using var ctx = new BlogContext();
await ctx.Database.EnsureDeletedAsync();
await ctx.Database.EnsureCreatedAsync();
var p = "foo";
_ = await ctx.Blogs.Where(x => x.Name1 == p || x.Name2.Contains(p)).FirstOrDefaultAsync();
public class BlogContext : DbContext
{
public DbSet<Blog> Blogs { get; set; }
protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder)
=> optionsBuilder
.UseSqlServer(@"Server=localhost;Database=test;User=SA;Password=Abcd5678;Connect Timeout=60;ConnectRetryCount=0;Encrypt=false")
.LogTo(Console.WriteLine, LogLevel.Information)
.EnableSensitiveDataLogging();
}
public class Blog
{
public int Id { get; set; }
[Column(TypeName = "varchar(6)")]
public string? Name1 { get; set; }
[Column(TypeName = "nvarchar(48)")]
public string? Name2 { get; set; }
} 7.0 SQL:
Note that CHARINDEX searches for @__p_0 in Name2 (mixing AnsiString and Unicode), although it should be searching for @__p_0_1. For comparison, if we remove the first condition and leave only the Contains, we get:
Finally, in 6.0 we generated only one parameter for everything, which was also incorrect (#19503 was the fix for that): 6.0 SQL (just one parameter):
|
Reopening to consider for servicing. |
Fixes dotnet#29646 (cherry picked from commit 3f82c2b)
When I search a string cross varchar and nvarchar columns, my condition's appearing order will generate different SQL parameter type, and get different result.
Here is my reproduce REPO:
https://github.com/ian90911/TestEfContainsBug/blob/master/TestEfContains/Program.cs
EF Core version:
Database provider: Microsoft.EntityFrameworkCore.SqlServer 6.0.9
Target framework: .NET 6.0
Operating system:
IDE: Visual Studio 2022 17.2.5
Consider a table have varchar and nvarchar column:
Case 1 : When query's condition in
Where
use varchar column first, it will get nothing:Case 2 : When use nvarchar column first, it will get expected result :
Case 3 : use
EF.Functions.Like()
It seems in case 1, ef core use Ansi string to declare parameter, which cause the empty result.
I can use
EF.Functions.Like()
to avoid condition order problem, but I think the result of case 1 is not as expected.The text was updated successfully, but these errors were encountered: