From e7752d9d5a286fbfd246377d30134308d6d28003 Mon Sep 17 00:00:00 2001 From: Shay Rojansky Date: Sat, 20 Jul 2024 16:44:28 +0200 Subject: [PATCH] Transform aggregate functions over subqueries on SQL Server Closes #34256 --- .../SqlExpressions/ProjectionExpression.cs | 1 - ...erverAggregateOverSubqueryPostprocessor.cs | 173 +++++++ .../SqlServerQueryCompilationContext.cs | 12 - .../SqlServerQueryTranslationPostprocessor.cs | 7 +- ...yableMethodTranslatingExpressionVisitor.cs | 141 ------ ...qlServerSqlTranslatingExpressionVisitor.cs | 22 - ...thwindAggregateOperatorsQueryCosmosTest.cs | 74 ++- ...orthwindAggregateOperatorsQueryTestBase.cs | 57 ++- ...indAggregateOperatorsQuerySqlServerTest.cs | 435 ++++++++++++------ ...thwindAggregateOperatorsQuerySqliteTest.cs | 9 +- 10 files changed, 561 insertions(+), 370 deletions(-) create mode 100644 src/EFCore.SqlServer/Query/Internal/SqlServerAggregateOverSubqueryPostprocessor.cs diff --git a/src/EFCore.Relational/Query/SqlExpressions/ProjectionExpression.cs b/src/EFCore.Relational/Query/SqlExpressions/ProjectionExpression.cs index 28c1c6bc33e..89d0a670bb8 100644 --- a/src/EFCore.Relational/Query/SqlExpressions/ProjectionExpression.cs +++ b/src/EFCore.Relational/Query/SqlExpressions/ProjectionExpression.cs @@ -23,7 +23,6 @@ public sealed class ProjectionExpression : Expression, IRelationalQuotableExpres /// any release. You should only use it directly in your code with extreme caution and knowing that /// doing so can result in application failures when updating to a new Entity Framework Core release. /// - [EntityFrameworkInternal] public ProjectionExpression(SqlExpression expression, string alias) { Expression = expression; diff --git a/src/EFCore.SqlServer/Query/Internal/SqlServerAggregateOverSubqueryPostprocessor.cs b/src/EFCore.SqlServer/Query/Internal/SqlServerAggregateOverSubqueryPostprocessor.cs new file mode 100644 index 00000000000..219e243e901 --- /dev/null +++ b/src/EFCore.SqlServer/Query/Internal/SqlServerAggregateOverSubqueryPostprocessor.cs @@ -0,0 +1,173 @@ +// Licensed to the .NET Foundation under one or more agreements. +// The .NET Foundation licenses this file to you under the MIT license. + +using System.Globalization; +using Microsoft.EntityFrameworkCore.Query.SqlExpressions; + +namespace Microsoft.EntityFrameworkCore.SqlServer.Query.Internal; + +/// +/// SQL Server doesn't support aggregate function invocations over subqueries, or other aggregate function invocations; this +/// postprocessor lifts such subqueries out to an OUTER APPLY/JOIN on the SELECT to work around this limitation. +/// +/// +/// This is an internal API that supports the Entity Framework Core infrastructure and not subject to +/// the same compatibility standards as public APIs. It may be changed or removed without notice in +/// any release. You should only use it directly in your code with extreme caution and knowing that +/// doing so can result in application failures when updating to a new Entity Framework Core release. +/// +public class SqlServerAggregateOverSubqueryPostprocessor(SqlAliasManager sqlAliasManager) : ExpressionVisitor +{ + private SelectExpression? _currentSelect; + private bool _inAggregateInvocation; + private List? _joinsToAdd; + private bool _isCorrelatedSubquery; + private HashSet? _tableAliasesInScope; + + /// + /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to + /// the same compatibility standards as public APIs. It may be changed or removed without notice in + /// any release. You should only use it directly in your code with extreme caution and knowing that + /// doing so can result in application failures when updating to a new Entity Framework Core release. + /// + protected override Expression VisitExtension(Expression node) + { + switch (node) + { + case SelectExpression select: + { + var (parentSelect, parentJoinsToAdd, parentAggregateInvocation) = (_currentSelect, _joinsToAdd, _inAggregateInvocation); + (_currentSelect, _joinsToAdd, _inAggregateInvocation) = (select, null, false); + + // If _tableAliasesInScope is non-null, we're tracking which table aliases are in scope for the current subquery, to detect + // correlated vs. uncorrelated subqueries. Add and remove the select's tables to _tableAliasInScope. + SelectExpression visitedSelect; + if (_tableAliasesInScope is null) + { + visitedSelect = (SelectExpression)base.VisitExtension(node); + } + else + { + List tableAliases = select.Tables.Select(t => t.UnwrapJoin().Alias).Where(a => a is not null).ToList()!; + _tableAliasesInScope.UnionWith(tableAliases); + visitedSelect = (SelectExpression)base.VisitExtension(node); + _tableAliasesInScope.ExceptWith(tableAliases); + } + + // A subquery is being lifted out somewhere inside this SelectExpression; add the join. + if (_joinsToAdd is not null) + { + visitedSelect = visitedSelect.Update( + [.. visitedSelect.Tables, .. _joinsToAdd], + visitedSelect.Predicate, + visitedSelect.GroupBy, + visitedSelect.Having, + visitedSelect.Projection, + visitedSelect.Orderings, + visitedSelect.Offset, + visitedSelect.Limit); + } + + (_currentSelect, _joinsToAdd, _inAggregateInvocation) = (parentSelect, parentJoinsToAdd, parentAggregateInvocation); + return visitedSelect; + } + + // TODO: We currently don't represent the fact that a function is an aggregate or not; so for now we just match a few well-known + // functions. Improve this in the future. + case SqlFunctionExpression function + when function.Name.ToLower(CultureInfo.InvariantCulture) is "sum" or "avg" or "min" or "max" or "count": + { + var parentInAggregateInvocation = _inAggregateInvocation; + _inAggregateInvocation = true; + var result = base.VisitExtension(function); + _inAggregateInvocation = parentInAggregateInvocation; + return result; + } + + // We have a scalar subquery inside an aggregate function argument; lift it out to an OUTER APPLY/CROSS JOIN that will be added + // to the containing SELECT, and return a ColumnExpression in its place that references that OUTER APPLY/CROSS JOIN. + + // Note that there's an assumption here that the query being lifted out will only ever return a single row (and column); + // if it didn't, the APPLY/JOIN would cause the principal row to get duplicated, producing incorrect results. + // It shouldn't be possible to produce such a state of affairs with LINQ, and since this is a scalar subquery, that SQL + // would fail in any case even if it weren't wrapped inside an aggregate function invocation. + case ScalarSubqueryExpression scalarSubquery when _inAggregateInvocation && _currentSelect is not null: + return LiftSubqueryToJoin(scalarSubquery.Subquery); + + // EXISTS is slightly more complicated; unlike a scalar subquery, where we can just lift out the wrapped subquery (it already + // returns a scalar), with EXISTS we need to conserve the ExistsExpression, pushing it down into a subquery which will become + // the OUTER APPLY (which needs to return a single boolean value). +#pragma warning disable EF1001 // SelectExpression constructor is internal + case ExistsExpression exists when _inAggregateInvocation && _currentSelect is not null: + { + var wrapperSubquery = new SelectExpression(exists, sqlAliasManager); + wrapperSubquery.ApplyProjection(); + return LiftSubqueryToJoin(wrapperSubquery); + } + + case InExpression { Subquery: SelectExpression } inExpression when _inAggregateInvocation && _currentSelect is not null: + { + var wrapperSubquery = new SelectExpression(inExpression, sqlAliasManager); + wrapperSubquery.ApplyProjection(); + return LiftSubqueryToJoin(wrapperSubquery); + } +#pragma warning restore EF1001 + + // If _tableAliasesInScope is non-null, we're tracking which table aliases are in scope for the current subquery, to detect + // correlated vs. uncorrelated subqueries. If we have a column referencing a table that isn't in the current scope, that means + // we're in a correlated subquery. + case ColumnExpression column when _tableAliasesInScope?.Contains(column.TableAlias) == false: + _isCorrelatedSubquery = true; + return base.VisitExtension(column); + + case ShapedQueryExpression shapedQueryExpression: + shapedQueryExpression = shapedQueryExpression + .UpdateQueryExpression(Visit(shapedQueryExpression.QueryExpression)) + .UpdateShaperExpression(Visit(shapedQueryExpression.ShaperExpression)); + return shapedQueryExpression.UpdateShaperExpression(Visit(shapedQueryExpression.ShaperExpression)); + + default: + return base.VisitExtension(node); + } + + ColumnExpression LiftSubqueryToJoin(SelectExpression subquery) + { + var (parentIsCorrelatedSubquery, parentTableAliasesInScope) = (_isCorrelatedSubquery, _tableAliasesInScope); + (_isCorrelatedSubquery, _tableAliasesInScope) = (false, new()); + + if (Visit(subquery) is not SelectExpression { Projection: [var projection] } visitedSubquery) + { + throw new UnreachableException("Invalid subquery"); + } + + // Since the subquery is currently a scalar subquery (or EXISTS), its doesn't have an alias for the subquery, and may not have + // an alias on its projection either. As part of lifting it out, we need to assign both aliases, so that the projection can be + // referenced. + var subqueryAlias = sqlAliasManager.GenerateTableAlias("subquery"); + if (projection.Alias is null or "") + { + projection = new ProjectionExpression(projection.Expression, "value"); + } + + visitedSubquery = visitedSubquery + .Update( + visitedSubquery.Tables, + visitedSubquery.Predicate, + visitedSubquery.GroupBy, + visitedSubquery.Having, + [projection], + visitedSubquery.Orderings, + visitedSubquery.Offset, + visitedSubquery.Limit) + .WithAlias(subqueryAlias); + + _joinsToAdd ??= new(); + _joinsToAdd.Add(_isCorrelatedSubquery ? new OuterApplyExpression(visitedSubquery) : new CrossJoinExpression(visitedSubquery)); + + (_isCorrelatedSubquery, _tableAliasesInScope) = (parentIsCorrelatedSubquery, parentTableAliasesInScope); + + return new ColumnExpression( + projection.Alias, subqueryAlias, projection.Expression.Type, projection.Expression.TypeMapping, nullable: true); + } + } +} diff --git a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryCompilationContext.cs b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryCompilationContext.cs index fc4ca3b3635..a5ea2cdf6e5 100644 --- a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryCompilationContext.cs +++ b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryCompilationContext.cs @@ -63,18 +63,6 @@ public override bool IsBuffering || (QuerySplittingBehavior == EntityFrameworkCore.QuerySplittingBehavior.SplitQuery && !_multipleActiveResultSetsEnabled); - /// - /// Tracks whether translation is currently within the argument of an aggregate method (e.g. MAX, COUNT); SQL Server does not - /// allow subqueries and aggregates in that context. - /// - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - public virtual bool InAggregateFunction { get; set; } - /// public override bool SupportsPrecompiledQuery => true; } diff --git a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryTranslationPostprocessor.cs b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryTranslationPostprocessor.cs index 8fa6a96a1e4..86608b53dee 100644 --- a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryTranslationPostprocessor.cs +++ b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryTranslationPostprocessor.cs @@ -17,6 +17,7 @@ namespace Microsoft.EntityFrameworkCore.SqlServer.Query.Internal; public class SqlServerQueryTranslationPostprocessor : RelationalQueryTranslationPostprocessor { private readonly SqlServerJsonPostprocessor _jsonPostprocessor; + private readonly SqlServerAggregateOverSubqueryPostprocessor _aggregatePostprocessor; private readonly SkipWithoutOrderByInSplitQueryVerifier _skipWithoutOrderByInSplitQueryVerifier = new(); private readonly SqlServerSqlTreePruner _pruner = new(); @@ -34,6 +35,7 @@ public SqlServerQueryTranslationPostprocessor( { _jsonPostprocessor = new SqlServerJsonPostprocessor( relationalDependencies.TypeMappingSource, relationalDependencies.SqlExpressionFactory, queryCompilationContext.SqlAliasManager); + _aggregatePostprocessor = new SqlServerAggregateOverSubqueryPostprocessor(queryCompilationContext.SqlAliasManager); } /// @@ -47,9 +49,10 @@ public override Expression Process(Expression query) var query1 = base.Process(query); var query2 = _jsonPostprocessor.Process(query1); - _skipWithoutOrderByInSplitQueryVerifier.Visit(query2); + var query3 = _aggregatePostprocessor.Visit(query2); + _skipWithoutOrderByInSplitQueryVerifier.Visit(query3); - return query2; + return query3; } /// diff --git a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryableMethodTranslatingExpressionVisitor.cs b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryableMethodTranslatingExpressionVisitor.cs index b5abe1a98c1..9ce6e9d5425 100644 --- a/src/EFCore.SqlServer/Query/Internal/SqlServerQueryableMethodTranslatingExpressionVisitor.cs +++ b/src/EFCore.SqlServer/Query/Internal/SqlServerQueryableMethodTranslatingExpressionVisitor.cs @@ -120,103 +120,6 @@ protected override Expression VisitExtension(Expression extensionExpression) return base.VisitExtension(extensionExpression); } - #region Aggregate functions - - // We override these for SQL Server to add tracking whether we're inside an aggregate function context, since SQL Server doesn't - // support subqueries (or aggregates) within them. - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateAverage(ShapedQueryExpression source, LambdaExpression? selector, Type resultType) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateAverage(source, selector, resultType); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateSum(ShapedQueryExpression source, LambdaExpression? selector, Type resultType) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateSum(source, selector, resultType); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateCount(ShapedQueryExpression source, LambdaExpression? predicate) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateCount(source, predicate); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateLongCount(ShapedQueryExpression source, LambdaExpression? predicate) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateLongCount(source, predicate); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateMax(ShapedQueryExpression source, LambdaExpression? selector, Type resultType) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateMax(source, selector, resultType); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateMin(ShapedQueryExpression source, LambdaExpression? selector, Type resultType) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - var result = base.TranslateMin(source, selector, resultType); - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - return result; - } - - #endregion Aggregate functions - /// /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to /// the same compatibility standards as public APIs. It may be changed or removed without notice in @@ -407,50 +310,6 @@ protected override ShapedQueryExpression TransformJsonQueryToTable(JsonQueryExpr false)); } - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override ShapedQueryExpression? TranslateContains(ShapedQueryExpression source, Expression item) - { - var translatedSource = base.TranslateContains(source, item); - - // SQL Server does not support subqueries inside aggregate functions (e.g. COUNT(SELECT * FROM OPENJSON(@p)...)). - // As a result, we track whether we're within an aggregate function; if we are, and we see the regular Contains translation - // (which uses IN with an OPENJSON subquery - incompatible), we transform it to the old-style IN+constants translation (as if a - // low SQL Server compatibility level were defined) - if (_queryCompilationContext.InAggregateFunction - && translatedSource is not null - && TryGetProjection(translatedSource, out var projection) - && projection is InExpression - { - Item: var translatedItem, - Subquery: - { - Tables: [SqlServerOpenJsonExpression { Arguments: [SqlParameterExpression parameter] } openJsonExpression], - Predicate: null, - GroupBy: [], - Having: null, - IsDistinct: false, - Limit: null, - Offset: null, - Orderings: [], - Projection: [{ Expression: ColumnExpression { Name: "value", TableAlias: var projectionTableAlias } }] - } - } - && projectionTableAlias == openJsonExpression.Alias) - { - var newInExpression = _sqlExpressionFactory.In(translatedItem, parameter); -#pragma warning disable EF1001 - return source.UpdateQueryExpression(new SelectExpression(newInExpression, _queryCompilationContext.SqlAliasManager)); -#pragma warning restore EF1001 - } - - return translatedSource; - } - /// /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to /// the same compatibility standards as public APIs. It may be changed or removed without notice in diff --git a/src/EFCore.SqlServer/Query/Internal/SqlServerSqlTranslatingExpressionVisitor.cs b/src/EFCore.SqlServer/Query/Internal/SqlServerSqlTranslatingExpressionVisitor.cs index 873ca89fa1d..905f70c4d32 100644 --- a/src/EFCore.SqlServer/Query/Internal/SqlServerSqlTranslatingExpressionVisitor.cs +++ b/src/EFCore.SqlServer/Query/Internal/SqlServerSqlTranslatingExpressionVisitor.cs @@ -524,28 +524,6 @@ private static string EscapeLikePattern(string pattern) return builder.ToString(); } - /// - /// This is an internal API that supports the Entity Framework Core infrastructure and not subject to - /// the same compatibility standards as public APIs. It may be changed or removed without notice in - /// any release. You should only use it directly in your code with extreme caution and knowing that - /// doing so can result in application failures when updating to a new Entity Framework Core release. - /// - protected override bool TryTranslateAggregateMethodCall( - MethodCallExpression methodCallExpression, - [NotNullWhen(true)] out SqlExpression? translation) - { - var previousInAggregateFunction = _queryCompilationContext.InAggregateFunction; - _queryCompilationContext.InAggregateFunction = true; - -#pragma warning disable EF1001 // Internal EF Core API usage. - var result = base.TryTranslateAggregateMethodCall(methodCallExpression, out translation); -#pragma warning restore EF1001 // Internal EF Core API usage. - - _queryCompilationContext.InAggregateFunction = previousInAggregateFunction; - - return result; - } - private Expression TranslateByteArrayElementAccess(Expression array, Expression index, Type resultType) { var visitedArray = Visit(array); diff --git a/test/EFCore.Cosmos.FunctionalTests/Query/NorthwindAggregateOperatorsQueryCosmosTest.cs b/test/EFCore.Cosmos.FunctionalTests/Query/NorthwindAggregateOperatorsQueryCosmosTest.cs index 8d6afb928ae..2f218d2f020 100644 --- a/test/EFCore.Cosmos.FunctionalTests/Query/NorthwindAggregateOperatorsQueryCosmosTest.cs +++ b/test/EFCore.Cosmos.FunctionalTests/Query/NorthwindAggregateOperatorsQueryCosmosTest.cs @@ -473,26 +473,50 @@ FROM root c """); }); - public override async Task Sum_over_subquery_is_client_eval(bool async) + public override async Task Sum_over_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Sum_over_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Sum_over_subquery(async)); AssertSql(); } - public override async Task Sum_over_nested_subquery_is_client_eval(bool async) + public override async Task Sum_over_nested_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Sum_over_nested_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Sum_over_nested_subquery(async)); AssertSql(); } - public override async Task Sum_over_min_subquery_is_client_eval(bool async) + public override async Task Sum_over_min_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Sum_over_min_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Sum_over_min_subquery(async)); + + AssertSql(); + } + + public override async Task Sum_over_scalar_returning_subquery(bool async) + { + // Aggregates. Issue #16146. + await AssertTranslationFailed(() => base.Sum_over_scalar_returning_subquery(async)); + + AssertSql(); + } + + public override async Task Sum_over_Any_subquery(bool async) + { + // Aggregates. Issue #16146. + await AssertTranslationFailed(() => base.Sum_over_Any_subquery(async)); + + AssertSql(); + } + + public override async Task Sum_over_uncorrelated_subquery(bool async) + { + // Aggregates. Issue #16146. + await AssertTranslationFailed(() => base.Sum_over_uncorrelated_subquery(async)); AssertSql(); } @@ -740,26 +764,26 @@ FROM root c """); }); - public override async Task Average_over_subquery_is_client_eval(bool async) + public override async Task Average_over_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Average_over_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Average_over_subquery(async)); AssertSql(); } - public override async Task Average_over_nested_subquery_is_client_eval(bool async) + public override async Task Average_over_nested_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Average_over_nested_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Average_over_nested_subquery(async)); AssertSql(); } - public override async Task Average_over_max_subquery_is_client_eval(bool async) + public override async Task Average_over_max_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Average_over_max_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Average_over_max_subquery(async)); AssertSql(); } @@ -864,26 +888,26 @@ FROM root c """); }); - public override async Task Min_over_subquery_is_client_eval(bool async) + public override async Task Min_over_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Min_over_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Min_over_subquery(async)); AssertSql(); } - public override async Task Min_over_nested_subquery_is_client_eval(bool async) + public override async Task Min_over_nested_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Min_over_nested_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Min_over_nested_subquery(async)); AssertSql(); } - public override async Task Min_over_max_subquery_is_client_eval(bool async) + public override async Task Min_over_max_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Min_over_max_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Min_over_max_subquery(async)); AssertSql(); } @@ -930,26 +954,26 @@ FROM root c """); }); - public override async Task Max_over_subquery_is_client_eval(bool async) + public override async Task Max_over_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Max_over_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Max_over_subquery(async)); AssertSql(); } - public override async Task Max_over_nested_subquery_is_client_eval(bool async) + public override async Task Max_over_nested_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Max_over_nested_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Max_over_nested_subquery(async)); AssertSql(); } - public override async Task Max_over_sum_subquery_is_client_eval(bool async) + public override async Task Max_over_sum_subquery(bool async) { // Aggregates. Issue #16146. - await AssertTranslationFailed(() => base.Max_over_sum_subquery_is_client_eval(async)); + await AssertTranslationFailed(() => base.Max_over_sum_subquery(async)); AssertSql(); } @@ -2012,7 +2036,7 @@ public override async Task Contains_with_local_anonymous_type_array_closure(bool public override async Task OfType_Select(bool async) { - // Contains over subquery. Issue #15937. + // Contains over subquery. Issue #17246. await AssertTranslationFailed(() => base.OfType_Select(async)); AssertSql(); diff --git a/test/EFCore.Specification.Tests/Query/NorthwindAggregateOperatorsQueryTestBase.cs b/test/EFCore.Specification.Tests/Query/NorthwindAggregateOperatorsQueryTestBase.cs index 0f5317eea88..1e75f6c4ca8 100644 --- a/test/EFCore.Specification.Tests/Query/NorthwindAggregateOperatorsQueryTestBase.cs +++ b/test/EFCore.Specification.Tests/Query/NorthwindAggregateOperatorsQueryTestBase.cs @@ -140,7 +140,7 @@ public virtual Task Sum_with_coalesce(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Sum_over_subquery_is_client_eval(bool async) + public virtual Task Sum_over_subquery(bool async) => AssertSum( async, ss => ss.Set(), @@ -148,7 +148,7 @@ public virtual Task Sum_over_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Sum_over_nested_subquery_is_client_eval(bool async) + public virtual Task Sum_over_nested_subquery(bool async) => AssertSum( async, ss => ss.Set(), @@ -156,12 +156,45 @@ public virtual Task Sum_over_nested_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Sum_over_min_subquery_is_client_eval(bool async) + public virtual Task Sum_over_min_subquery(bool async) => AssertSum( async, ss => ss.Set(), selector: c => c.Orders.Sum(o => 5 + o.OrderDetails.Min(od => od.ProductID))); + [ConditionalTheory] + [MemberData(nameof(IsAsyncData))] + public virtual Task Sum_over_scalar_returning_subquery(bool async) + => AssertSum( + async, + ss => ss.Set(), + ss => ss.Set(), + actualSelector: c => c.Orders.FirstOrDefault().OrderID, + expectedSelector: c => c.Orders.Any() ? c.Orders.FirstOrDefault().OrderID : 0); + + [ConditionalTheory] + [MemberData(nameof(IsAsyncData))] + public virtual Task Sum_over_Any_subquery(bool async) + => AssertSum( + async, + ss => ss.Set(), + selector: c => c.Orders.Any() ? c.Orders.FirstOrDefault().OrderID : 0); + + [ConditionalTheory] + [MemberData(nameof(IsAsyncData))] + public virtual async Task Sum_over_uncorrelated_subquery(bool async) + { + await using var context = CreateContext(); + + // AssertSum() doesn't provide access to the ISetSource in order to do the uncorrelated query, so we test this manually. + // Note: the Count predicate is specified to work around #34261. + var result = async + ? await context.Set().SumAsync(c => context.Set().Count(o => o.OrderID > 10300)) + : context.Set().Sum(c => context.Set().Count(o => o.OrderID > 10300)); + + AssertEqual(70707, result); + } + [ConditionalTheory] [MemberData(nameof(IsAsyncData))] public virtual Task Sum_on_float_column(bool async) @@ -238,7 +271,7 @@ public virtual Task Average_with_coalesce(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Average_over_subquery_is_client_eval(bool async) + public virtual Task Average_over_subquery(bool async) => AssertAverage( async, ss => ss.Set(), @@ -246,7 +279,7 @@ public virtual Task Average_over_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Average_over_nested_subquery_is_client_eval(bool async) + public virtual Task Average_over_nested_subquery(bool async) => AssertAverage( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), @@ -254,7 +287,7 @@ public virtual Task Average_over_nested_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Average_over_max_subquery_is_client_eval(bool async) + public virtual Task Average_over_max_subquery(bool async) => AssertAverage( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), @@ -407,7 +440,7 @@ public virtual Task Min_with_coalesce(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Min_over_subquery_is_client_eval(bool async) + public virtual Task Min_over_subquery(bool async) => AssertMin( async, ss => ss.Set(), @@ -415,7 +448,7 @@ public virtual Task Min_over_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Min_over_nested_subquery_is_client_eval(bool async) + public virtual Task Min_over_nested_subquery(bool async) => AssertMin( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), @@ -423,7 +456,7 @@ public virtual Task Min_over_nested_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Min_over_max_subquery_is_client_eval(bool async) + public virtual Task Min_over_max_subquery(bool async) => AssertMin( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), @@ -454,7 +487,7 @@ public virtual Task Max_with_coalesce(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Max_over_subquery_is_client_eval(bool async) + public virtual Task Max_over_subquery(bool async) => AssertMax( async, ss => ss.Set(), @@ -462,7 +495,7 @@ public virtual Task Max_over_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Max_over_nested_subquery_is_client_eval(bool async) + public virtual Task Max_over_nested_subquery(bool async) => AssertMax( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), @@ -470,7 +503,7 @@ public virtual Task Max_over_nested_subquery_is_client_eval(bool async) [ConditionalTheory] [MemberData(nameof(IsAsyncData))] - public virtual Task Max_over_sum_subquery_is_client_eval(bool async) + public virtual Task Max_over_sum_subquery(bool async) => AssertMax( async, ss => ss.Set().OrderBy(c => c.CustomerID).Take(3), diff --git a/test/EFCore.SqlServer.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqlServerTest.cs b/test/EFCore.SqlServer.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqlServerTest.cs index 4db5547df79..399805bd820 100644 --- a/test/EFCore.SqlServer.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqlServerTest.cs +++ b/test/EFCore.SqlServer.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqlServerTest.cs @@ -1,7 +1,7 @@ // Licensed to the .NET Foundation under one or more agreements. // The .NET Foundation licenses this file to you under the MIT license. -using Microsoft.Data.SqlClient; +using Xunit.Sdk; namespace Microsoft.EntityFrameworkCore.Query; @@ -700,63 +700,127 @@ WHERE [p].[ProductID] < 40 """); } - public override async Task Sum_over_subquery_is_client_eval(bool async) + public override async Task Sum_over_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Sum_over_subquery_is_client_eval(async))).Number); + await base.Sum_over_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT COALESCE(SUM(( - SELECT COALESCE(SUM([o].[OrderID]), 0) +SELECT COALESCE(SUM([s].[value]), 0) +FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM([o].[OrderID]), 0) AS [value] FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID])), 0) + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s] +"""); + } + + public override async Task Sum_over_nested_subquery(bool async) + { + await base.Sum_over_nested_subquery(async); + + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" + AssertSql( + """ +SELECT COALESCE(SUM([s0].[value]), 0) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM(5 + [s].[value]), 0) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT COALESCE(SUM([o0].[ProductID]), 0) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } - public override async Task Sum_over_nested_subquery_is_client_eval(bool async) + public override async Task Sum_over_min_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Sum_over_nested_subquery_is_client_eval(async))).Number); + await base.Sum_over_min_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT COALESCE(SUM(( - SELECT COALESCE(SUM(5 + ( - SELECT COALESCE(SUM([o0].[ProductID]), 0) +SELECT COALESCE(SUM([s0].[value]), 0) +FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM(5 + [s].[value]), 0) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT MIN([o0].[ProductID]) AS [value] FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])), 0) + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s0] +"""); + } + + public override async Task Sum_over_scalar_returning_subquery(bool async) + { + await base.Sum_over_scalar_returning_subquery(async); + + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" + AssertSql( + """ +SELECT COALESCE(SUM([s].[OrderID]), 0) +FROM [Customers] AS [c] +OUTER APPLY ( + SELECT TOP(1) [o].[OrderID] FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID])), 0) + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s] +"""); + } + + public override async Task Sum_over_Any_subquery(bool async) + { + await base.Sum_over_Any_subquery(async); + + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" + AssertSql( + """ +SELECT COALESCE(SUM(CASE + WHEN [s].[value] = CAST(1 AS bit) THEN [s0].[OrderID] + ELSE 0 +END), 0) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN EXISTS ( + SELECT 1 + FROM [Orders] AS [o] + WHERE [c].[CustomerID] = [o].[CustomerID]) THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] +OUTER APPLY ( + SELECT TOP(1) [o0].[OrderID] + FROM [Orders] AS [o0] + WHERE [c].[CustomerID] = [o0].[CustomerID] +) AS [s0] """); } - public override async Task Sum_over_min_subquery_is_client_eval(bool async) + public override async Task Sum_over_uncorrelated_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Sum_over_min_subquery_is_client_eval(async))).Number); + await base.Sum_over_uncorrelated_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT COALESCE(SUM(( - SELECT COALESCE(SUM(5 + ( - SELECT MIN([o0].[ProductID]) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])), 0) - FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID])), 0) +SELECT COALESCE(SUM([s].[value]), 0) FROM [Customers] AS [c] +CROSS JOIN ( + SELECT COUNT(*) AS [value] + FROM [Orders] AS [o] + WHERE [o].[OrderID] > 10300 +) AS [s] """); } @@ -865,75 +929,80 @@ WHERE [p].[ProductID] < 40 """); } - public override async Task Average_over_subquery_is_client_eval(bool async) + public override async Task Average_over_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Average_over_subquery_is_client_eval(async))).Number); + await base.Average_over_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT AVG(CAST(( - SELECT COALESCE(SUM([o].[OrderID]), 0) - FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID]) AS float)) +SELECT AVG(CAST([s].[value] AS float)) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM([o].[OrderID]), 0) AS [value] + FROM [Orders] AS [o] + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s] """); } - public override async Task Average_over_nested_subquery_is_client_eval(bool async) + public override async Task Average_over_nested_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Average_over_nested_subquery_is_client_eval(async))).Number); + // Expected: 46.7126322751323 + // Actual: 46.713333 + await Assert.ThrowsAsync(() => base.Average_over_nested_subquery(async)); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT AVG(CAST(( - SELECT AVG(5.0E0 + ( - SELECT AVG(CAST([o0].[ProductID] AS float)) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID]) AS decimal(18,2))) +SELECT AVG(CAST([s0].[value] AS decimal(18,2))) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT AVG(5.0E0 + [s].[value]) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT AVG(CAST([o0].[ProductID] AS float)) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } - public override async Task Average_over_max_subquery_is_client_eval(bool async) + public override async Task Average_over_max_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Average_over_max_subquery_is_client_eval(async))).Number); + // Expected: 59.841269841269866666666666667 + // Actual: 59.843333 + await Assert.ThrowsAsync(() => base.Average_over_max_subquery(async)); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT AVG(CAST(( - SELECT AVG(CAST(5 + ( - SELECT MAX([o0].[ProductID]) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID]) AS float)) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID]) AS decimal(18,2))) +SELECT AVG(CAST([s0].[value] AS decimal(18,2))) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT AVG(CAST(5 + [s].[value] AS float)) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT MAX([o0].[ProductID]) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } @@ -1013,75 +1082,76 @@ WHERE [p].[ProductID] < 40 """); } - public override async Task Min_over_subquery_is_client_eval(bool async) + public override async Task Min_over_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Min_over_subquery_is_client_eval(async))).Number); + await base.Min_over_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT MIN(( - SELECT COALESCE(SUM([o].[OrderID]), 0) - FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID])) +SELECT MIN([s].[value]) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM([o].[OrderID]), 0) AS [value] + FROM [Orders] AS [o] + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s] """); } - public override async Task Min_over_nested_subquery_is_client_eval(bool async) + public override async Task Min_over_nested_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Min_over_nested_subquery_is_client_eval(async))).Number); + await base.Min_over_nested_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT MIN(( - SELECT MIN(5 + ( - SELECT MIN([o0].[ProductID]) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID])) +SELECT MIN([s0].[value]) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT MIN(5 + [s].[value]) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT MIN([o0].[ProductID]) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } - public override async Task Min_over_max_subquery_is_client_eval(bool async) + public override async Task Min_over_max_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Min_over_max_subquery_is_client_eval(async))).Number); + await base.Min_over_max_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT MIN(( - SELECT MIN(5 + ( - SELECT MAX([o0].[ProductID]) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID])) +SELECT MIN([s0].[value]) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT MIN(5 + [s].[value]) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT MAX([o0].[ProductID]) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } @@ -1119,75 +1189,76 @@ WHERE [p].[ProductID] < 40 """); } - public override async Task Max_over_subquery_is_client_eval(bool async) + public override async Task Max_over_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Max_over_subquery_is_client_eval(async))).Number); + await base.Max_over_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ -SELECT MAX(( - SELECT COALESCE(SUM([o].[OrderID]), 0) - FROM [Orders] AS [o] - WHERE [c].[CustomerID] = [o].[CustomerID])) +SELECT MAX([s].[value]) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT COALESCE(SUM([o].[OrderID]), 0) AS [value] + FROM [Orders] AS [o] + WHERE [c].[CustomerID] = [o].[CustomerID] +) AS [s] """); } - public override async Task Max_over_nested_subquery_is_client_eval(bool async) + public override async Task Max_over_nested_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Max_over_nested_subquery_is_client_eval(async))).Number); + await base.Max_over_nested_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT MAX(( - SELECT MAX(5 + ( - SELECT MAX([o0].[ProductID]) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID])) +SELECT MAX([s0].[value]) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT MAX(5 + [s].[value]) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT MAX([o0].[ProductID]) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } - public override async Task Max_over_sum_subquery_is_client_eval(bool async) + public override async Task Max_over_sum_subquery(bool async) { - // Aggregates. Issue #15937. - Assert.Equal( - 130, - (await Assert.ThrowsAsync( - async () => await base.Max_over_sum_subquery_is_client_eval(async))).Number); + await base.Max_over_sum_subquery(async); + // #34256: rewrite query to avoid "Cannot perform an aggregate function on an expression containing an aggregate or a subquery" AssertSql( """ @__p_0='3' -SELECT MAX(( - SELECT MAX(5 + ( - SELECT COALESCE(SUM([o0].[ProductID]), 0) - FROM [Order Details] AS [o0] - WHERE [o].[OrderID] = [o0].[OrderID])) - FROM [Orders] AS [o] - WHERE [c0].[CustomerID] = [o].[CustomerID])) +SELECT MAX([s0].[value]) FROM ( SELECT TOP(@__p_0) [c].[CustomerID] FROM [Customers] AS [c] ORDER BY [c].[CustomerID] ) AS [c0] +OUTER APPLY ( + SELECT MAX(5 + [s].[value]) AS [value] + FROM [Orders] AS [o] + OUTER APPLY ( + SELECT COALESCE(SUM([o0].[ProductID]), 0) AS [value] + FROM [Order Details] AS [o0] + WHERE [o].[OrderID] = [o0].[OrderID] + ) AS [s] + WHERE [c0].[CustomerID] = [o].[CustomerID] +) AS [s0] """); } @@ -2218,7 +2289,6 @@ ELSE CAST(0 AS bit) public override async Task Contains_with_local_anonymous_type_array_closure(bool async) { - // Aggregates. Issue #15937. await AssertTranslationFailed(() => base.Contains_with_local_anonymous_type_array_closure(async)); AssertSql(); @@ -2947,10 +3017,21 @@ public override async Task Contains_inside_aggregate_function_with_GroupBy(bool AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT COUNT(CASE - WHEN [c].[City] IN (N'London', N'Berlin') THEN 1 + WHEN [s].[value] = CAST(1 AS bit) THEN 1 END) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] + ) AND [c].[City] IS NOT NULL THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] GROUP BY [c].[Country] """); } @@ -2961,11 +3042,22 @@ public override async Task Contains_inside_Average_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT AVG(CASE - WHEN [c].[City] IN (N'London', N'Berlin') THEN 1.0E0 + WHEN [s].[value] = CAST(1 AS bit) THEN 1.0E0 ELSE 0.0E0 END) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] + ) AND [c].[City] IS NOT NULL THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] """); } @@ -2975,11 +3067,22 @@ public override async Task Contains_inside_Sum_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT COALESCE(SUM(CASE - WHEN [c].[City] IN (N'London', N'Berlin') THEN 1 + WHEN [s].[value] = CAST(1 AS bit) THEN 1 ELSE 0 END), 0) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] + ) AND [c].[City] IS NOT NULL THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] """); } @@ -2989,9 +3092,14 @@ public override async Task Contains_inside_Count_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT COUNT(*) FROM [Customers] AS [c] -WHERE [c].[City] IN (N'London', N'Berlin') +WHERE [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] +) """); } @@ -3001,9 +3109,14 @@ public override async Task Contains_inside_LongCount_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT COUNT_BIG(*) FROM [Customers] AS [c] -WHERE [c].[City] IN (N'London', N'Berlin') +WHERE [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] +) """); } @@ -3013,11 +3126,22 @@ public override async Task Contains_inside_Max_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT MAX(CASE - WHEN [c].[City] IN (N'London', N'Berlin') THEN 1 + WHEN [s].[value] = CAST(1 AS bit) THEN 1 ELSE 0 END) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] + ) AND [c].[City] IS NOT NULL THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] """); } @@ -3027,11 +3151,22 @@ public override async Task Contains_inside_Min_without_GroupBy(bool async) AssertSql( """ +@__cities_0='["London","Berlin"]' (Size = 4000) + SELECT MIN(CASE - WHEN [c].[City] IN (N'London', N'Berlin') THEN 1 + WHEN [s].[value] = CAST(1 AS bit) THEN 1 ELSE 0 END) FROM [Customers] AS [c] +OUTER APPLY ( + SELECT CASE + WHEN [c].[City] IN ( + SELECT [c0].[value] + FROM OPENJSON(@__cities_0) WITH ([value] nvarchar(15) '$') AS [c0] + ) AND [c].[City] IS NOT NULL THEN CAST(1 AS bit) + ELSE CAST(0 AS bit) + END AS [value] +) AS [s] """); } diff --git a/test/EFCore.Sqlite.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqliteTest.cs b/test/EFCore.Sqlite.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqliteTest.cs index 2c07e6a4fec..b60bc64d9ea 100644 --- a/test/EFCore.Sqlite.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqliteTest.cs +++ b/test/EFCore.Sqlite.FunctionalTests/Query/NorthwindAggregateOperatorsQuerySqliteTest.cs @@ -65,9 +65,9 @@ SELECT ef_avg(ef_divide(CAST("o"."Quantity" AS TEXT), '2.0')) - public override async Task Average_over_max_subquery_is_client_eval(bool async) + public override async Task Average_over_max_subquery(bool async) { - await base.Average_over_max_subquery_is_client_eval(async); + await base.Average_over_max_subquery(async); AssertSql( """ @@ -89,9 +89,9 @@ LIMIT @__p_0 """); } - public override async Task Average_over_nested_subquery_is_client_eval(bool async) + public override async Task Average_over_nested_subquery(bool async) { - await base.Average_over_nested_subquery_is_client_eval(async); + await base.Average_over_nested_subquery(async); AssertSql( """ @@ -120,7 +120,6 @@ public override async Task Multiple_collection_navigation_with_FirstOrDefault_ch () => base.Multiple_collection_navigation_with_FirstOrDefault_chained(async))).Message); public override async Task Contains_with_local_anonymous_type_array_closure(bool async) - // Aggregates. Issue #15937. => await AssertTranslationFailed(() => base.Contains_with_local_anonymous_type_array_closure(async)); public override async Task Contains_with_local_tuple_array_closure(bool async)