-
Notifications
You must be signed in to change notification settings - Fork 2k
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Adding documentation for custom function mapping
Fixes #500
- Loading branch information
Showing
11 changed files
with
498 additions
and
14 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
140 changes: 140 additions & 0 deletions
140
entity-framework/core/querying/user-defined-function-mapping.md
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,140 @@ | ||
--- | ||
title: User-defined function mapping - EF Core | ||
description: Mapping user-defined functions to database functions | ||
author: maumar | ||
ms.date: 11/23/2020 | ||
uid: core/user-defined-function-mapping | ||
--- | ||
# User-defined function mapping | ||
|
||
EF Core allows for using user-defined SQL functions in queries. To do that, the functions need to be mapped to a CLR method during model configuration. When translating the LINQ query to SQL, the user-defined function is called instead of the CLR function it has been mapped to. | ||
|
||
## Mapping a method to a SQL function | ||
|
||
To illustrate how user-defined function mapping work, let's define the following entities: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#Entities)] | ||
|
||
And the following model configuration: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#EntityConfiguration)] | ||
|
||
Blog can have many posts and each post can have many comments. | ||
|
||
Next, create the user-defined function `CommentedPostCountForBlog`, which returns the count of posts with at least one comment for a given blog, based on the blog `Id`: | ||
|
||
```sql | ||
CREATE FUNCTION dbo.CommentedPostCountForBlog(@id int) | ||
RETURNS int | ||
AS | ||
BEGIN | ||
RETURN (SELECT COUNT(*) | ||
FROM [Posts] AS [p] | ||
WHERE ([p].[BlogId] = @id) AND (( | ||
SELECT COUNT(*) | ||
FROM [Comments] AS [c] | ||
WHERE [p].[PostId] = [c].[PostId]) > 0)); | ||
END | ||
``` | ||
|
||
To use this function in EF Core, we define the following CLR method, which we map to the user-defined function: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#BasicFunctionDefinition)] | ||
|
||
The body of the CLR method is not important. The method will not be invoked client-side, unless EF Core can't translate its arguments. If the arguments can be translated, EF Core only cares about the method signature. | ||
|
||
> [!NOTE] | ||
> In the example, the method is defined on `DbContext`, but it can also be defined as a static method inside other classes. | ||
This function definition can now be associated with user-defined function in the model configuration: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#BasicFunctionConfiguration)] | ||
|
||
By default, EF Core tries to map CLR function to a user-defined function with the same name. If the names differ, we can use `HasName` to provide the correct name for the user-defined function we want to map to. | ||
|
||
Now, executing the following query: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Program.cs#BasicQuery)] | ||
|
||
Will produce this SQL: | ||
|
||
```sql | ||
SELECT [b].[BlogId], [b].[Rating], [b].[Url] | ||
FROM [Blogs] AS [b] | ||
WHERE [dbo].[CommentedPostCountForBlog]([b].[BlogId]) > 1 | ||
``` | ||
|
||
## Mapping a method to a custom SQL | ||
|
||
EF Core also allows for user-defined functions that get converted to a specific SQL. The SQL expression is provided using `HasTranslation` method during user-defined function configuration. | ||
|
||
In the example below, we'll create a function that computes percentage difference between two integers. | ||
|
||
The CLR method is as follows: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#HasTranslationFunctionDefinition)] | ||
|
||
The function definition is as follows: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#HasTranslationFunctionConfiguration)] | ||
|
||
Once we define the function, it can be used in the query. Instead of calling database function, EF Core will translate the method body directly into SQL based on the SQL expression tree constructed from the HasTranslation. The following LINQ query: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Program.cs#HasTranslationQuery)] | ||
|
||
Produces the following SQL: | ||
|
||
```sql | ||
SELECT 100 * (ABS([p].[BlogId] - 3) / ((CAST([p].[BlogId] AS float) + 3) / 2)) | ||
FROM [Posts] AS [p] | ||
``` | ||
|
||
## Mapping a queryable function to a table-valued function | ||
|
||
EF Core also supports mapping to a table-valued function using a user-defined CLR method returning an `IQueryable` of entity types, allowing EF Core to map TVFs with parameters. The process is similar to mapping a scalar user-defined function to a SQL function: we need a TVF in the database, a CLR function that is used in the LINQ queries, and a mapping between the two. | ||
|
||
As an example, we'll use a table-valued function that returns all posts having at least one comment that meets a given "Like" threshold: | ||
|
||
```sql | ||
CREATE FUNCTION dbo.PostsWithPopularComments(@likeThreshold int) | ||
RETURNS TABLE | ||
AS | ||
RETURN | ||
( | ||
SELECT [p].[PostId], [p].[BlogId], [p].[Content], [p].[Rating], [p].[Title] | ||
FROM [Posts] AS [p] | ||
WHERE ( | ||
SELECT COUNT(*) | ||
FROM [Comments] AS [c] | ||
WHERE ([p].[PostId] = [c].[PostId]) AND ([c].[Likes] >= @likeThreshold)) > 0 | ||
) | ||
``` | ||
|
||
The CLR method signature is as follows: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#QueryableFunctionDefinition)] | ||
|
||
> [!TIP] | ||
> The `FromExpression` call in the CLR function body allows for the function to be used instead of a regular DbSet. | ||
And below is the mapping: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#QueryableFunctionConfigurationHasDbFunction)] | ||
|
||
> [!CAUTION] | ||
> Until [issue 23408](https://github.com/dotnet/efcore/issues/23408) is fixed, mapping to an `IQueryable` of entity types overrides the default mapping to a table for the DbSet. If necessary - for example when the entity is not keyless - mapping to the table must be specified explicitly using `ToTable` method. | ||
> [!NOTE] | ||
> Queryable function must be mapped to a table-valued function and can't use of `HasTranslation`. | ||
When the function is mapped, the following query: | ||
|
||
[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Program.cs#TableValuedFunctionQuery)] | ||
|
||
Produces: | ||
|
||
```sql | ||
SELECT [p].[PostId], [p].[BlogId], [p].[Content], [p].[Rating], [p].[Title] | ||
FROM [dbo].[PostsWithPopularComments](@likeThreshold) AS [p] | ||
ORDER BY [p].[Rating] | ||
``` |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,15 +1,38 @@ | ||
using System; | ||
using System.Collections.Generic; | ||
using EFModeling.Conventions.EntityTypes; | ||
using Microsoft.EntityFrameworkCore; | ||
using System.Linq; | ||
using System.Text; | ||
using System.Threading.Tasks; | ||
|
||
namespace EFModeling.Conventions | ||
{ | ||
class Program | ||
{ | ||
static void Main(string[] args) | ||
{ | ||
using (var context = new MyContextWithFunctionMapping()) | ||
{ | ||
context.Database.EnsureDeleted(); | ||
context.Database.EnsureCreated(); | ||
|
||
context.Database.ExecuteSqlRaw( | ||
@"CREATE FUNCTION dbo.BlogsWithMultiplePosts() | ||
RETURNS TABLE | ||
AS | ||
RETURN | ||
( | ||
SELECT b.Url, COUNT(p.BlogId) AS PostCount | ||
FROM Blogs AS b | ||
JOIN Posts AS p ON b.BlogId = p.BlogId | ||
GROUP BY b.BlogId, b.Url | ||
HAVING COUNT(p.BlogId) > 1 | ||
)"); | ||
|
||
#region ToFunctionQuery | ||
var query = from b in context.Set<BlogWithMultiplePosts>() | ||
where b.PostCount > 3 | ||
select new { b.Url, b.PostCount }; | ||
#endregion | ||
var result = query.ToList(); | ||
} | ||
} | ||
} | ||
} |
Oops, something went wrong.