Skip to content

Condition's order will cause different result when using .Contains() to search string cross varchar and nvarchar columns #29646

@ian90911

Description

@ian90911

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:

CREATE TABLE [dbo].[test](
	[stockId] [varchar](6) NOT NULL,
	[stockName] [nvarchar](48) NOT NULL,
	CONSTRAINT [pk_test] PRIMARY KEY CLUSTERED ([stockId] ASC)
)

Case 1 : When query's condition in Where use varchar column first, it will get nothing:

var query1 = await db.Tests.Where(x => x.StockId == queryName || x.StockName.Contains(queryName)).FirstOrDefaultAsync();
//result is null
      Generated query execution expression: 
      'queryContext => ShapedQueryCompilingExpressionVisitor.SingleOrDefaultAsync<Test>(
          asyncEnumerable: new SingleQueryingEnumerable<Test>(
              (RelationalQueryContext)queryContext, 
              RelationalCommandCache.SelectExpression(
                  Projection Mapping:
                      EmptyProjectionMember -> Dictionary<IProperty, int> { [Property: Test.StockId (string) Required PK AfterSave:Throw MaxLength(6) Ansi, 0], [Property: Test.StockName (string) Required MaxLength(48), 1] }
                  SELECT TOP(1) t.stockId, t.stockName
                  FROM test AS t
                  WHERE (t.stockId == @__queryName_0) || ((@__queryName_0 LIKE N'') || (CHARINDEX(@__queryName_0, t.stockName) > 0))), 
              Func<QueryContext, DbDataReader, ResultContext, SingleQueryResultCoordinator, Test>, 
              TestEfContains.MyDbContext, 
              False, 
              False, 
              True
          ), 
          cancellationToken: queryContext.CancellationToken)'

Case 2 : When use nvarchar column first, it will get expected result :

var query2 = await db.Tests.Where(x => x.StockName.Contains(queryName) || x.StockId == queryName).FirstOrDefaultAsync();
//print data
      Generated query execution expression: 
      'queryContext => ShapedQueryCompilingExpressionVisitor.SingleOrDefaultAsync<Test>(
          asyncEnumerable: new SingleQueryingEnumerable<Test>(
              (RelationalQueryContext)queryContext, 
              RelationalCommandCache.SelectExpression(
                  Projection Mapping:
                      EmptyProjectionMember -> Dictionary<IProperty, int> { [Property: Test.StockId (string) Required PK AfterSave:Throw MaxLength(6) Ansi, 0], [Property: Test.StockName (string) Required MaxLength(48), 1] }
                  SELECT TOP(1) t.stockId, t.stockName
                  FROM test AS t
                  WHERE ((@__queryName_0 LIKE N'') || (CHARINDEX(@__queryName_0, t.stockName) > 0)) || (t.stockId == @__queryName_0)), 
              Func<QueryContext, DbDataReader, ResultContext, SingleQueryResultCoordinator, Test>, 
              TestEfContains.MyDbContext, 
              False, 
              False, 
              True
          ), 
          cancellationToken: queryContext.CancellationToken)'

Case 3 : use EF.Functions.Like()

var query3 = await db.Tests.Where(x => x.StockId == queryName || EF.Functions.Like(x.StockName, $"%{queryName}%")).FirstOrDefaultAsync();
      Generated query execution expression: 
      'queryContext => ShapedQueryCompilingExpressionVisitor.SingleOrDefaultAsync<Test>(
          asyncEnumerable: new SingleQueryingEnumerable<Test>(
              (RelationalQueryContext)queryContext, 
              RelationalCommandCache.SelectExpression(
                  Projection Mapping:
                      EmptyProjectionMember -> Dictionary<IProperty, int> { [Property: Test.StockId (string) Required PK AfterSave:Throw MaxLength(6) Ansi, 0], [Property: Test.StockName (string) Required MaxLength(48), 1] }
                  SELECT TOP(1) t.stockId, t.stockName
                  FROM test AS t
                  WHERE (t.stockId == @__queryName_0) || (t.stockName LIKE @__Format_2)), 
              Func<QueryContext, DbDataReader, ResultContext, SingleQueryResultCoordinator, Test>, 
              TestEfContains.MyDbContext, 
              False, 
              False, 
              True
          ), 
          cancellationToken: queryContext.CancellationToken)'

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.

Metadata

Metadata

Assignees

Type

Projects

No projects

Milestone

Relationships

None yet

Development

No branches or pull requests

Issue actions