-
Notifications
You must be signed in to change notification settings - Fork 3.2k
New issue
Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.
By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.
Already on GitHub? Sign in to your account
GroupBy generates invalid SQL when using custom database function #29638
Comments
Confirmed that this repros; not a regression (failed in EF Core 6.0 as well). Somewhat simplified repro: await using var ctx = new BlogContext();
await ctx.Database.EnsureDeletedAsync();
await ctx.Database.EnsureCreatedAsync();
var orderIds = new [] { "id1", "id2" };
_ = ctx.Orders
.Where(c => ctx
.Split(string.Join(",", orderIds), ",")
.Select(s => s.Value)
.Contains(c.OrderId))
.Select(c => new
{
c.Project.Code,
c.Project.Revenue
})
.GroupBy(c => new { c.Code })
.Select(c => new
{
c.Key.Code,
Sum = c.Sum(e => e.Revenue)
}).ToList();
public class BlogContext : DbContext
{
public DbSet<Project> Projects { get; set; }
public DbSet<Order> Orders { 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();
[Keyless]
public class StringSplitResult
{
public string Value { get; set; }
}
[DbFunction(IsBuiltIn = true, Name = "STRING_SPLIT")]
public IQueryable<StringSplitResult> Split(string source, string separator)
=> FromExpression(() => Split(source, separator));
}
public class Project
{
public Guid ProjectId { get; set; }
public decimal Revenue { get; set; }
public string Code { get; set; }
}
public class Order
{
public string OrderId { get; set; }
public Guid ProjectId { get; set; }
public Project Project { get; set; }
} SQL: SELECT [p].[Code], (
SELECT COALESCE(SUM([p1].[Revenue]), 0.0)
FROM [Orders] AS [o0]
INNER JOIN [Projects] AS [p0] ON [o0].[ProjectId] = [p0].[ProjectId]
INNER JOIN [Projects] AS [p1] ON [o0].[ProjectId] = [p1].[ProjectId]
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS [s0]
WHERE [s0].[Value] = [o0].[OrderId]) AND [p].[Code] = [p0].[Code]) AS [Sum]
FROM [Orders] AS [o]
INNER JOIN [Projects] AS [p] ON [o].[ProjectId] = [p].[ProjectId]
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS [s0]
WHERE [s].[Value] = [o].[OrderId]) -- [s] looks like it should be [s0
GROUP BY [p].[Code] We seem to be generating the incorrect alias in the WHERE subquery ([s] instead of [s0]). As a side-note, it seems like the whole subquery shouldn't be there in the projection, since the TVF check is only a filter (so should be in WHERE only)? |
@andreikarkkanen We are facing the same issue on one query with GroupBy. Others do not seem affected. While not being ideal, @maumar provided a workaround by adding a Distinct. As he said, this is hacky but it is fixing our query and we may go that route for the time being. |
We have this query expression: Projection Mapping:
Code -> p.Code
Sum -> (
SELECT SUM(p0.Revenue)
FROM Orders AS o
INNER JOIN Projects AS p ON o.ProjectId == p.ProjectId
INNER JOIN Projects AS p0 ON o.ProjectId == p0.ProjectId
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS s
WHERE s.Value == o.Order29638Id) && (p.Code == p.Code))
SELECT 1
FROM Orders AS o
INNER JOIN Projects AS p ON o.ProjectId == p.ProjectId
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS s
WHERE s.Value == o.Order29638Id)
GROUP BY p.Code so we have this SelectExpression SELECT 1
FROM Orders AS o
INNER JOIN Projects AS p ON o.ProjectId == p.ProjectId
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS s
WHERE s.Value == o.Order29638Id)
GROUP BY p.Code and try to apply this into the projection: SELECT SUM(p0.Revenue)
FROM Orders AS o
INNER JOIN Projects AS p ON o.ProjectId == p.ProjectId
INNER JOIN Projects AS p0 ON o.ProjectId == p0.ProjectId
WHERE EXISTS (
SELECT 1
FROM STRING_SPLIT(@__Join_1, N',') AS s
WHERE s.Value == o.Order29638Id) && (p.Code == p.Code)) since the alias |
problem is that |
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
… database function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes dotnet#29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Also added defensive check that throws if we encounter TableExpressionBase that doesn't implement the cloning logic, so that this never happens again. Fixes #29638
…ase function (#30617) Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Also added defensive check that throws if we encounter TableExpressionBase that doesn't implement the cloning logic, so that this never happens again. Fixes #29638
@ajcvickers, @maumar: Is there any chance that this bug will be fixed in EF Core 7.0 too? |
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
…ase function Problem is that CloningExpressionVisitor doesn't have proper handling for TableValuedFunctionExpression, and therefore goes through default expression visitor pattern (visit all children, check if there are any changes, if there are return new, if not return the same). Since there are no changes, the same instance is returned from cloning, and causes the problem. Fix is to add proper handling of TVFExpression in the CloningExpressionVisitor so that it produces a proper copy. Fixes #29638
When executing the following query an exception is thrown
Microsoft.Data.SqlClient.SqlException (0x80131904): The multi-part identifier "s.Value" could not be bound.
The incorrect part is
The .AsQueriable() solves a cache plan pollution problem. The full solution is in the attachment.
ConsoleApp1.zip
Or
Environment details:
EF Core: 7.0.0
Database provider: Microsoft.EntityFrameworkCore.SqlServer
Target framework: .NET 7.0
Operating system: Windows 10
IDE: Visual Studio 2022 17.4.1
The text was updated successfully, but these errors were encountered: