Skip to content

Commit

Permalink
Adding documentation for custom function mapping
Browse files Browse the repository at this point in the history
Fixes #500
  • Loading branch information
maumar committed Dec 2, 2020
1 parent d106985 commit 2972db4
Show file tree
Hide file tree
Showing 15 changed files with 903 additions and 12 deletions.
151 changes: 151 additions & 0 deletions entity-framework/core/modeling/custom-function-mapping.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,151 @@
---
title: User-defined function mapping - EF Core
description: Mapping user-defined functions to database functions
author: maumar
ms.date: 11/23/2020
uid: core/modeling/custom-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 custom function mapping work, let's define the following entities:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/Blog.cs#Entity)]

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/Post.cs#Entity)]

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/Tag.cs#Entity)]

And the following model configuration:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#EntityConfiguration)]

Blog can have many posts, each post can be tagged with multiple tags, and each tag can be associated with multiple posts; we have set up a many-to-many relationship.

Next, create the user-defined function `DistinctTagsCountForBlogPosts`, which returns the count of unique tags associated with all the posts of a given blog, based on the blog `Id`:

```sql
CREATE FUNCTION dbo.DistinctTagsCountForBlogPosts(@id int)
RETURNS int
AS
BEGIN
RETURN (SELECT COUNT(*) FROM(
SELECT DISTINCT t.TagId FROM dbo.Tags AS t
JOIN dbo.PostTag AS pt ON t.TagId = pt.TagId
JOIN dbo.Posts AS p ON p.PostId = pt.PostId
JOIN dbo.Blogs AS b ON b.BlogId = p.BlogId
WHERE b.BlogId = @id) AS subquery);
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/Modeling/CustomFunctionMapping/BloggingContext.cs#BasicFunctionDefinition)]

In the example, the method is defined on `DbContext`, but it can also be defined as a static method in other places. Note that the body of the CLR method is not important, as it will never be invoked client-side; EF Core only looks at the method signature.

This function definition can now be associated with user-defined function in the model configuration:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#BasicFunctionConfiguration)]

> [!NOTE]
> 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/Modeling/CustomFunctionMapping/Program.cs#BasicQuery)]

Will produce this SQL:

```sql
SELECT [b].[BlogId], [b].[Rating], [b].[Url]
FROM [Blogs] AS [b]
WHERE [dbo].[DistinctTagsCountForBlogPosts]([b].[BlogId]) > 2
```

## Mapping a method to a custom SQL

EF Core also allows for user-defined functions that get converted to a specific SQL. This can be done by specifying a SQL expression using the [Microsoft.EntityFrameworkCore.Query.SqlExpressions](/dotnet/api/microsoft.entityframeworkcore.query.sqlexpressions) API. The SQL expression is provided using `HasTranslation` method during user-defined function configuration.

In the example below, we'll create a function that computes difference between two integers.

The CLR method is as follows:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#HasTranslationFunctionDefinition)]

The function definition is as follows:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#HasTranslationFunctionConfiguration)]

Note that [SqlExpressionFactory](/dotnet/api/microsoft.entityframeworkcore.query.sqlexpressionfactory) is used to construct a `SqlExpression` tree.

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 SQL expression tree constructed from the HasTranslation.

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/Program.cs#HasTranslationQuery)]

Produces the following SQL:

```sql
SELECT [p].[PostId], [p].[BlogId], [p].[Content], [p].[Rating], [p].[Title]
FROM [Posts] AS [p]
WHERE [p].[PostId] < ABS([p].[BlogId] - 3)
```

## Mapping a Queryable function to a table-valued gunction

EF Core also supports mapping to a table-valued function using a user-defined CLR function 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 marked with a specific tag:

```sql
CREATE FUNCTION dbo.PostsTaggedWith(@tag varchar(max))
RETURNS @posts TABLE
(
PostId int not null,
BlogId int not null,
Content nvarchar(max),
Rating int not null,
Title nvarchar(max)
)
AS
BEGIN
INSERT INTO @posts
SELECT p.PostId, p.BlogId, p.Content, p.Rating, p.Title
FROM Posts AS p
WHERE EXISTS (
SELECT 1
FROM PostTag AS pt
INNER JOIN Tags AS t ON pt.TagId = t.TagId
WHERE (p.PostId = pt.PostId) AND (t.TagId = @tag))

RETURN
END
```

The CLR function signature is as follows:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#QueryableFunctionDefinition)]

And below is the mapping:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/BloggingContext.cs#QueryableFunctionConfigurationHasDbFunction)]

> [!CAUTION]
> 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.
When the function is mapped, the following query:

[!code-csharp[Main](../../../samples/core/Modeling/CustomFunctionMapping/Program.cs#TableValuedFunctionQuery)]

Produces:

```sql
SELECT [t].[TagId], [p].[PostId], [p].[BlogId], [p].[Content], [p].[Rating], [p].[Title]
FROM [Tags] AS [t]
OUTER APPLY [dbo].[PostsTaggedWith]([t].[TagId]) AS [p]
WHERE CAST(LEN([t].[TagId]) AS int) < 10
ORDER BY [t].[TagId], [p].[PostId]
```
47 changes: 47 additions & 0 deletions entity-framework/core/modeling/entity-types.md
Original file line number Diff line number Diff line change
Expand Up @@ -99,3 +99,50 @@ Entity types can be mapped to database views using the Fluent API.

> [!TIP]
> To test entity types mapped to views using the in-memory provider map them to a query via `ToInMemoryQuery`. See a [runnable sample](https://github.com/dotnet/EntityFramework.Docs/tree/master/samples/core/Miscellaneous/Testing/ItemsWebApi/) using this technique for more details.
## Table-valued function mapping

It's possible to map an entity type to a table-valued function (TVF) instead of a table in the database. To illustrate this, let's define another entity that represents blog with multiple posts. In the example, the entity is [keyless](xref:core/modeling/keyless-entity-types), but it doesn't have to be.

[!code-csharp[Main](../../../samples/core/Modeling/Conventions/EntityTypes.cs#BlogWithMultiplePostsEntity)]

Next, create the following table-valued function in the database, which returns only blogs with multiple posts as well as the number of posts associated with each of these blogs:

```sql
CREATE FUNCTION dbo.BlogsWithMultiplePosts()
RETURNS @blogs TABLE
(
Url nvarchar(max),
PostCount int not null
)
AS
BEGIN
INSERT INTO @blogs
SELECT b.Url, COUNT(p.BlogId)
FROM Blogs AS b
JOIN Posts AS p ON b.BlogId = p.BlogId
GROUP BY b.BlogId, b.Url
HAVING COUNT(p.BlogId) > 1

RETURN
END
```

Now, the `DbSet<BlogWithMultiplePost>` can be mapped to this function in a following way:

[!code-csharp[Main](../../../samples/core/Modeling/Conventions/EntityTypes.cs#QueryableFunctionConfigurationToFunction)]

> [!NOTE]
> In order to map an entity to a table-valued function the function must be parameterless. Also, the names of the entity properties must match the names of the columns returned by the TVF; any discrepancies can be configured using `HasColumnName` method, just like when mapping to a regular table.
When the DbSet is mapped to a table-valued function, the query:

[!code-csharp[Main](../../../samples/core/Modeling/Conventions/Program.cs#ToFunctionQuery)]

Produces the following SQL:

```sql
SELECT [b].[Url], [b].[PostCount]
FROM [dbo].[BlogsWithMultiplePosts]() AS [b]
WHERE [b].[PostCount] > 3
```
154 changes: 154 additions & 0 deletions entity-framework/core/querying/user-defined-function-mapping.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,154 @@
---
title: User-defined function mapping - EF Core
description: Mapping user-defined functions to database functions
author: maumar
ms.date: 11/23/2020
uid: core/modeling/custom-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#BlogEntity)]

[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#PostEntity)]

[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#CommentEntity)]

And the following model configuration:

[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#EntityConfiguration)]

Blog can have many posts, each post can be tagged with multiple tags, and each tag can be associated with multiple posts; we have set up a many-to-many relationship.

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)]

In the example, the method is defined on `DbContext`, but it can also be defined as a static method in other places. Note that the body of the CLR method is not important, as it will never be invoked client-side; EF Core only looks at the method signature.

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)]

> [!NOTE]
> 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. This can be done by specifying a SQL expression using the [Microsoft.EntityFrameworkCore.Query.SqlExpressions](/dotnet/api/microsoft.entityframeworkcore.query.sqlexpressions) API. The SQL expression is provided using `HasTranslation` method during user-defined function configuration.

In the example below, we'll create a function that computes 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)]

Note that [SqlExpressionFactory](/dotnet/api/microsoft.entityframeworkcore.query.sqlexpressionfactory) is used to construct a `SqlExpression` tree.

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. The following LINQ query:

[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Program.cs#HasTranslationQuery)]

Produces the following SQL:

```sql
SELECT [p].[PostId], [p].[BlogId], [p].[Content], [p].[Rating], [p].[Title]
FROM [Posts] AS [p]
WHERE [p].[PostId] < CASE
WHEN [p].[BlogId] > 3 THEN [p].[BlogId] - 3
ELSE 3 - [p].[BlogId]
END
```

## Mapping a Queryable function to a table-valued gunction

EF Core also supports mapping to a table-valued function using a user-defined CLR function 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 @posts TABLE
(
PostId int not null,
BlogId int not null,
Content nvarchar(max),
Rating int not null,
Title nvarchar(max)
)
AS
BEGIN
INSERT INTO @posts
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

RETURN
END
```

The CLR function 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 the root of the EF Core query, meaning it can be used instead of a regular DbSet.
And below is the mapping:

[!code-csharp[Main](../../../samples/core/Querying/UserDefinedFunctionMapping/Model.cs#QueryableFunctionConfigurationHasDbFunction)]

> [!CAUTION]
> 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.
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]
```
2 changes: 2 additions & 0 deletions entity-framework/index.yml
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,8 @@ additionalContent:
text: "Raw SQL queries"
- url: core/querying/filters.md
text: "Global query filters"
- url: core/querying/user-defined-function-mapping.md
text: "User-defined function mapping"
# Card
- title: Manage database schemas
links:
Expand Down
2 changes: 2 additions & 0 deletions entity-framework/toc.yml
Original file line number Diff line number Diff line change
Expand Up @@ -191,6 +191,8 @@
href: core/querying/filters.md
- name: Query tags
href: core/querying/tags.md
- name: User-defined function mapping
href: core/querying/user-defined-function-mapping.md
- name: How queries work
href: core/querying/how-query-works.md

Expand Down
3 changes: 2 additions & 1 deletion samples/core/Modeling/Conventions/Conventions.csproj
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,8 @@
</PropertyGroup>

<ItemGroup>
<PackageReference Include="Microsoft.EntityFrameworkCore.Relational" Version="3.1.8" />
<PackageReference Include="Microsoft.EntityFrameworkCore.Relational" Version="5.0.0" />
<PackageReference Include="Microsoft.EntityFrameworkCore.SqlServer" Version="5.0.0" />
</ItemGroup>

</Project>
Loading

0 comments on commit 2972db4

Please sign in to comment.