From f8c0098215c5f8e9589b8c6c7151e8fec6612512 Mon Sep 17 00:00:00 2001 From: maumar Date: Mon, 16 Nov 2020 10:52:08 -0800 Subject: [PATCH] Adding documentation for custom function mapping Fixes #500 --- .../core/modeling/custom-function-mapping.md | 151 +++++++++++++++++ .../core/modeling/entity-types.md | 47 ++++++ .../querying/user-defined-function-mapping.md | 154 +++++++++++++++++ entity-framework/index.yml | 2 + entity-framework/toc.yml | 2 + .../Modeling/Conventions/Conventions.csproj | 3 +- .../core/Modeling/Conventions/EntityTypes.cs | 26 +++ samples/core/Modeling/Conventions/Program.cs | 37 ++++- .../CustomFunctionMapping.csproj | 15 ++ .../Modeling/CustomFunctionMapping/Model.cs | 156 ++++++++++++++++++ .../Modeling/CustomFunctionMapping/Program.cs | 79 +++++++++ .../UserDefinedFunctionMapping/Model.cs | 135 +++++++++++++++ .../UserDefinedFunctionMapping/Program.cs | 73 ++++++++ .../UserDefinedFunctionMapping.csproj | 15 ++ samples/core/Samples.sln | 21 ++- 15 files changed, 904 insertions(+), 12 deletions(-) create mode 100644 entity-framework/core/modeling/custom-function-mapping.md create mode 100644 entity-framework/core/querying/user-defined-function-mapping.md create mode 100644 samples/core/Modeling/CustomFunctionMapping/CustomFunctionMapping.csproj create mode 100644 samples/core/Modeling/CustomFunctionMapping/Model.cs create mode 100644 samples/core/Modeling/CustomFunctionMapping/Program.cs create mode 100644 samples/core/Querying/UserDefinedFunctionMapping/Model.cs create mode 100644 samples/core/Querying/UserDefinedFunctionMapping/Program.cs create mode 100644 samples/core/Querying/UserDefinedFunctionMapping/UserDefinedFunctionMapping.csproj diff --git a/entity-framework/core/modeling/custom-function-mapping.md b/entity-framework/core/modeling/custom-function-mapping.md new file mode 100644 index 0000000000..b9e056e0da --- /dev/null +++ b/entity-framework/core/modeling/custom-function-mapping.md @@ -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] +``` diff --git a/entity-framework/core/modeling/entity-types.md b/entity-framework/core/modeling/entity-types.md index 5c81e65e42..4ac9cf9d09 100644 --- a/entity-framework/core/modeling/entity-types.md +++ b/entity-framework/core/modeling/entity-types.md @@ -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` 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 +``` diff --git a/entity-framework/core/querying/user-defined-function-mapping.md b/entity-framework/core/querying/user-defined-function-mapping.md new file mode 100644 index 0000000000..ba2174dfb3 --- /dev/null +++ b/entity-framework/core/querying/user-defined-function-mapping.md @@ -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 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 [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] +``` diff --git a/entity-framework/index.yml b/entity-framework/index.yml index 961fc8cc8e..57072dd32f 100644 --- a/entity-framework/index.yml +++ b/entity-framework/index.yml @@ -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: diff --git a/entity-framework/toc.yml b/entity-framework/toc.yml index 1da653ab69..58186cfa4e 100644 --- a/entity-framework/toc.yml +++ b/entity-framework/toc.yml @@ -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 diff --git a/samples/core/Modeling/Conventions/Conventions.csproj b/samples/core/Modeling/Conventions/Conventions.csproj index 0441a21dd2..d9fb862ac6 100644 --- a/samples/core/Modeling/Conventions/Conventions.csproj +++ b/samples/core/Modeling/Conventions/Conventions.csproj @@ -8,7 +8,8 @@ - + + diff --git a/samples/core/Modeling/Conventions/EntityTypes.cs b/samples/core/Modeling/Conventions/EntityTypes.cs index d154d71e07..216614b8f8 100644 --- a/samples/core/Modeling/Conventions/EntityTypes.cs +++ b/samples/core/Modeling/Conventions/EntityTypes.cs @@ -38,4 +38,30 @@ public class AuditEntry public string Action { get; set; } } #endregion + + #region BlogWithMultiplePostsEntity + public class BlogWithMultiplePosts + { + public string Url { get; set; } + public int PostCount { get; set; } + } + #endregion + + public class MyContextWithFunctionMapping : DbContext + { + public DbSet Blogs { get; set; } + public DbSet Posts { get; set; } + + protected override void OnModelCreating(ModelBuilder modelBuilder) + { + #region QueryableFunctionConfigurationToFunction + modelBuilder.Entity().HasNoKey().ToFunction("BlogsWithMultiplePosts"); + #endregion + } + + protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder) + { + optionsBuilder.UseSqlServer(@"Server=(localdb)\mssqllocaldb;Database=EFModeling.EntityTypeToFunctionMapping;Trusted_Connection=True;ConnectRetryCount=0"); + } + } } diff --git a/samples/core/Modeling/Conventions/Program.cs b/samples/core/Modeling/Conventions/Program.cs index 6be3a54b3e..620e182373 100644 --- a/samples/core/Modeling/Conventions/Program.cs +++ b/samples/core/Modeling/Conventions/Program.cs @@ -1,8 +1,6 @@ -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 { @@ -10,6 +8,37 @@ 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 @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"); + + #region ToFunctionQuery + var query = from b in context.Set() + where b.PostCount > 3 + select new { b.Url, b.PostCount }; + #endregion + var result = query.ToList(); + } } } } diff --git a/samples/core/Modeling/CustomFunctionMapping/CustomFunctionMapping.csproj b/samples/core/Modeling/CustomFunctionMapping/CustomFunctionMapping.csproj new file mode 100644 index 0000000000..f87d591d5d --- /dev/null +++ b/samples/core/Modeling/CustomFunctionMapping/CustomFunctionMapping.csproj @@ -0,0 +1,15 @@ + + + + Exe + netcoreapp3.1 + EFModeling.CustomFunctionMapping + EFModeling.CustomFunctionMapping + + + + + + + + diff --git a/samples/core/Modeling/CustomFunctionMapping/Model.cs b/samples/core/Modeling/CustomFunctionMapping/Model.cs new file mode 100644 index 0000000000..8fc75fc4d2 --- /dev/null +++ b/samples/core/Modeling/CustomFunctionMapping/Model.cs @@ -0,0 +1,156 @@ +using Microsoft.EntityFrameworkCore; +using Microsoft.EntityFrameworkCore.Infrastructure; +using Microsoft.EntityFrameworkCore.Query; +using Microsoft.EntityFrameworkCore.Query.SqlExpressions; +using System; +using System.Collections.Generic; +using System.Linq; + +namespace EFModeling.CustomFunctionMapping +{ +// #region BlogEntity +// public class Blog +// { +// public int BlogId { get; set; } +// public string Url { get; set; } +// public int? Rating { get; set; } + +// public List Posts { get; set; } +// } +// #endregion + +// #region PostEntity +// public class Post +// { +// public int PostId { get; set; } +// public string Title { get; set; } +// public string Content { get; set; } +// public int Rating { get; set; } +// public int BlogId { get; set; } + +// public Blog Blog { get; set; } +// public List Comments { get; set; } +// } +// #endregion + +// #region CommentEntity +// public class Comment +// { +// public int CommentId { get; set; } +// public string Text { get; set; } +// public int Likes { get; set; } +// public int PostId { get; set; } + +// public Post Post { get; set; } +// } +// #endregion + +// public class BloggingContext : DbContext +// { +// public DbSet Blogs { get; set; } +// public DbSet Posts { get; set; } +// public DbSet Comments { get; set; } + +// #region BasicFunctionDefinition +// public int ActivePostCountForBlog(int blogId) +// => throw new NotSupportedException(); +// #endregion + +// #region HasTranslationFunctionDefinition +// public int Difference(int first, int second) +// => throw new NotSupportedException(); +// #endregion + +// #region QueryableFunctionDefinition +// public IQueryable PostsTaggedWith(string tag) +// => FromExpression(() => PostsTaggedWith(tag)); +// #endregion + +// protected override void OnModelCreating(ModelBuilder modelBuilder) +// { +// #region EntityConfiguration +// modelBuilder.Entity() +// .HasMany(b => b.Posts) +// .WithOne(p => p.Blog); +//// .OnDelete(DeleteBehavior.NoAction); + +// modelBuilder.Entity() +// .HasMany(p => p.Comments) +// .WithOne(c => c.Post); +//// .OnDelete(DeleteBehavior.NoAction); +// #endregion + +// //modelBuilder.Entity() +// // .HasMany(p => p.Tags) +// // .WithMany(t => t.Posts) +// // .UsingEntity>( +// // "PostTag", +// // r => r.HasOne().WithMany().HasForeignKey("TagId"), +// // l => l.HasOne().WithMany().HasForeignKey("PostId"), +// // je => +// // { +// // je.HasKey("PostId", "TagId"); +// // je.HasData( +// // new { PostId = 1, TagId = "general" }, +// // new { PostId = 1, TagId = "informative" }, +// // new { PostId = 2, TagId = "classic" }, +// // new { PostId = 3, TagId = "opinion" }, +// // new { PostId = 4, TagId = "opinion" }, +// // new { PostId = 4, TagId = "informative" }); +// // }); + +// modelBuilder.Entity() +// .HasData( +// new Blog { BlogId = 1, Url = @"https://devblogs.microsoft.com/dotnet", Rating = 5 }, +// new Blog { BlogId = 2, Url = @"https://mytravelblog.com/", Rating = 4 }); + +// modelBuilder.Entity() +// .HasData( +// new Post { PostId = 1, BlogId = 1, Title = "What's new", Content = "Lorem ipsum dolor sit amet", Rating = 5 }, +// new Post { PostId = 2, BlogId = 2, Title = "Around the World in Eighty Days", Content = "consectetur adipiscing elit", Rating = 5 }, +// new Post { PostId = 3, BlogId = 2, Title = "Glamping *is* the way", Content = "sed do eiusmod tempor incididunt", Rating = 4 }, +// new Post { PostId = 4, BlogId = 2, Title = "Travel in the time of pandemic", Content = "ut labore et dolore magna aliqua", Rating = 3 }); + +// modelBuilder.Entity() +// .HasData( +// new Comment { CommentId = 1, PostId = 1, Text = "Exciting!", Likes = 3 }, +// new Comment { CommentId = 2, PostId = 1, Text = "Dotnet is useless - why use C# when you can write super fast assembly code instead?", Likes = 0 }, +// new Comment { CommentId = 3, PostId = 2, Text = "Didn't think you would make it!", Likes = 3 }, +// new Comment { CommentId = 4, PostId = 2, Text = "Are you going to try 70 days next time?", Likes = 5 }, +// new Comment { CommentId = 5, PostId = 2, Text = "Good thing the earth is round :)", Likes = 5 }, +// new Comment { CommentId = 6, PostId = 3, Text = "I couldn't agree with you more", Likes = 2 }); + +// #region BasicFunctionConfiguration +// modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(ActivePostCountForBlog), new[] { typeof(int) })) +// .HasName("CommentedPostCountForBlog"); +// #endregion + +// #region HasTranslationFunctionConfiguration +// var sqlExpressionFactory = this.GetService(); + +// // CASE +// // WHEN first > second THEN first - second +// // ELSE second - first +// modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(Difference), new[] { typeof(int), typeof(int) })) +// .HasTranslation(args => sqlExpressionFactory.Case( +// new CaseWhenClause[] +// { +// new CaseWhenClause( +// sqlExpressionFactory.GreaterThan(args.First(), args.Skip(1).First()), +// sqlExpressionFactory.Subtract(args.First(), args.Skip(1).First())) +// }, +// sqlExpressionFactory.Subtract(args.Skip(1).First(), args.First()))); +// #endregion + +// #region QueryableFunctionConfigurationHasDbFunction +// modelBuilder.Entity().ToTable("Posts"); +// modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(PostsTaggedWith), new[] { typeof(string) })); +// #endregion +// } + +// protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder) +// { +// optionsBuilder.UseSqlServer(@"Server=(localdb)\mssqllocaldb;Database=EFModeling.CustomFunctionMapping;Trusted_Connection=True;ConnectRetryCount=0"); +// } +// } +} diff --git a/samples/core/Modeling/CustomFunctionMapping/Program.cs b/samples/core/Modeling/CustomFunctionMapping/Program.cs new file mode 100644 index 0000000000..9b8c4b7467 --- /dev/null +++ b/samples/core/Modeling/CustomFunctionMapping/Program.cs @@ -0,0 +1,79 @@ +using Microsoft.EntityFrameworkCore; +using System.Linq; + +namespace EFModeling.CustomFunctionMapping +{ + class Program + { + static void Main(string[] args) + { + } + } + // using var context = new BloggingContext(); + // context.Database.EnsureDeleted(); + // context.Database.EnsureCreated(); + + // context.Database.ExecuteSqlRaw( + // @"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"); + + // context.Database.ExecuteSqlRaw( + // @"CREATE FUNCTION dbo.PostsTaggedWith(@likeTreshold 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] >= @likeTreshold)) > 0 + + // RETURN + // END"); + + // var likeTreshold = 1; + // var blah = context.Posts.Where(p => p.Comments.Where(c => c.Likes >= likeTreshold).Count() > 0).ToList(); + + + + // #region BasicQuery + // var query1 = from b in context.Blogs + // where context.ActivePostCountForBlog(b.BlogId) > 2 + // select b; + // #endregion + // var result1 = query1.ToList(); + + // #region HasTranslationQuery + // var query2 = from p in context.Posts + // where p.PostId < context.Difference(p.BlogId, 3) + // select p; + // #endregion + // var result2 = query2.ToList(); + + // //#region TableValuedFunctionQuery + // //var query4 = from t in context.Tags + // // where t.TagId.Length < 10 + // // select context.PostsTaggedWith(t.TagId).ToList(); + // //#endregion + // //var result4 = query4.ToList(); + // } + //} +} diff --git a/samples/core/Querying/UserDefinedFunctionMapping/Model.cs b/samples/core/Querying/UserDefinedFunctionMapping/Model.cs new file mode 100644 index 0000000000..43e920eaf8 --- /dev/null +++ b/samples/core/Querying/UserDefinedFunctionMapping/Model.cs @@ -0,0 +1,135 @@ +using Microsoft.EntityFrameworkCore; +using Microsoft.EntityFrameworkCore.Infrastructure; +using Microsoft.EntityFrameworkCore.Query; +using Microsoft.EntityFrameworkCore.Query.SqlExpressions; +using System; +using System.Collections.Generic; +using System.Linq; + +namespace EFQuerying.UserDefinedFunctionMapping +{ + #region BlogEntity + public class Blog + { + public int BlogId { get; set; } + public string Url { get; set; } + public int? Rating { get; set; } + + public List Posts { get; set; } + } + #endregion + + #region PostEntity + public class Post + { + public int PostId { get; set; } + public string Title { get; set; } + public string Content { get; set; } + public int Rating { get; set; } + public int BlogId { get; set; } + + public Blog Blog { get; set; } + public List Comments { get; set; } + } + #endregion + + #region CommentEntity + public class Comment + { + public int CommentId { get; set; } + public string Text { get; set; } + public int Likes { get; set; } + public int PostId { get; set; } + + public Post Post { get; set; } + } + #endregion + + public class BloggingContext : DbContext + { + public DbSet Blogs { get; set; } + public DbSet Posts { get; set; } + public DbSet Comments { get; set; } + + #region BasicFunctionDefinition + public int ActivePostCountForBlog(int blogId) + => throw new NotSupportedException(); + #endregion + + #region HasTranslationFunctionDefinition + public int Difference(int first, int second) + => throw new NotSupportedException(); + #endregion + + #region QueryableFunctionDefinition + public IQueryable PostsWithPopularComments(int likeThreshold) + => FromExpression(() => PostsWithPopularComments(likeThreshold)); + #endregion + + protected override void OnModelCreating(ModelBuilder modelBuilder) + { + #region EntityConfiguration + modelBuilder.Entity() + .HasMany(b => b.Posts) + .WithOne(p => p.Blog); + + modelBuilder.Entity() + .HasMany(p => p.Comments) + .WithOne(c => c.Post); + #endregion + + modelBuilder.Entity() + .HasData( + new Blog { BlogId = 1, Url = @"https://devblogs.microsoft.com/dotnet", Rating = 5 }, + new Blog { BlogId = 2, Url = @"https://mytravelblog.com/", Rating = 4 }); + + modelBuilder.Entity() + .HasData( + new Post { PostId = 1, BlogId = 1, Title = "What's new", Content = "Lorem ipsum dolor sit amet", Rating = 5 }, + new Post { PostId = 2, BlogId = 2, Title = "Around the World in Eighty Days", Content = "consectetur adipiscing elit", Rating = 5 }, + new Post { PostId = 3, BlogId = 2, Title = "Glamping *is* the way", Content = "sed do eiusmod tempor incididunt", Rating = 4 }, + new Post { PostId = 4, BlogId = 2, Title = "Travel in the time of pandemic", Content = "ut labore et dolore magna aliqua", Rating = 3 }); + + modelBuilder.Entity() + .HasData( + new Comment { CommentId = 1, PostId = 1, Text = "Exciting!", Likes = 3 }, + new Comment { CommentId = 2, PostId = 1, Text = "Dotnet is useless - why use C# when you can write super fast assembly code instead?", Likes = 0 }, + new Comment { CommentId = 3, PostId = 2, Text = "Didn't think you would make it!", Likes = 3 }, + new Comment { CommentId = 4, PostId = 2, Text = "Are you going to try 70 days next time?", Likes = 5 }, + new Comment { CommentId = 5, PostId = 2, Text = "Good thing the earth is round :)", Likes = 5 }, + new Comment { CommentId = 6, PostId = 3, Text = "I couldn't agree with you more", Likes = 2 }); + + #region BasicFunctionConfiguration + modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(ActivePostCountForBlog), new[] { typeof(int) })) + .HasName("CommentedPostCountForBlog"); + #endregion + + #region HasTranslationFunctionConfiguration + var sqlExpressionFactory = this.GetService(); + + // CASE + // WHEN first > second THEN first - second + // ELSE second - first + modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(Difference), new[] { typeof(int), typeof(int) })) + .HasTranslation(args => sqlExpressionFactory.Case( + new CaseWhenClause[] + { + new CaseWhenClause( + sqlExpressionFactory.GreaterThan(args.First(), args.Skip(1).First()), + sqlExpressionFactory.Subtract(args.First(), args.Skip(1).First())) + }, + sqlExpressionFactory.Subtract(args.Skip(1).First(), args.First()))); + #endregion + + #region QueryableFunctionConfigurationHasDbFunction + modelBuilder.Entity().ToTable("Posts"); + modelBuilder.HasDbFunction(typeof(BloggingContext).GetMethod(nameof(PostsWithPopularComments), new[] { typeof(int) })); + #endregion + } + + protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder) + { + optionsBuilder.UseSqlServer(@"Server=(localdb)\mssqllocaldb;Database=EFQuerying.UserDefinedFunctionMapping;Trusted_Connection=True;ConnectRetryCount=0"); + } + } +} diff --git a/samples/core/Querying/UserDefinedFunctionMapping/Program.cs b/samples/core/Querying/UserDefinedFunctionMapping/Program.cs new file mode 100644 index 0000000000..0a6aae3d80 --- /dev/null +++ b/samples/core/Querying/UserDefinedFunctionMapping/Program.cs @@ -0,0 +1,73 @@ +using Microsoft.EntityFrameworkCore; +using System.Linq; + +namespace EFQuerying.UserDefinedFunctionMapping +{ + class Program + { + static void Main(string[] args) + { + using var context = new BloggingContext(); + context.Database.EnsureDeleted(); + context.Database.EnsureCreated(); + + context.Database.ExecuteSqlRaw( + @"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"); + + context.Database.ExecuteSqlRaw( + @"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"); + + #region BasicQuery + var query1 = from b in context.Blogs + where context.ActivePostCountForBlog(b.BlogId) > 1 + select b; + #endregion + var result1 = query1.ToList(); + + #region HasTranslationQuery + var query2 = from p in context.Posts + where p.PostId < context.Difference(p.BlogId, 3) + select p; + #endregion + var result2 = query2.ToList(); + + #region TableValuedFunctionQuery + var likeThreshold = 3; + var query3 = from p in context.PostsWithPopularComments(likeThreshold) + orderby p.Rating + select p; + #endregion + var result3 = query3.ToList(); + } + } +} diff --git a/samples/core/Querying/UserDefinedFunctionMapping/UserDefinedFunctionMapping.csproj b/samples/core/Querying/UserDefinedFunctionMapping/UserDefinedFunctionMapping.csproj new file mode 100644 index 0000000000..0432988ed9 --- /dev/null +++ b/samples/core/Querying/UserDefinedFunctionMapping/UserDefinedFunctionMapping.csproj @@ -0,0 +1,15 @@ + + + + Exe + netcoreapp3.1 + EFQuerying.UserDefinedFunctionMapping + EFQuerying.UserDefinedFunctionMapping + + + + + + + + diff --git a/samples/core/Samples.sln b/samples/core/Samples.sln index 85361c9c03..8bd590af43 100644 --- a/samples/core/Samples.sln +++ b/samples/core/Samples.sln @@ -113,19 +113,21 @@ Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "WebApplication1.Migrations" EndProject Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "WebApplication1", "Schemas\ThreeProjectMigrations\WebApplication1\WebApplication1.csproj", "{A15F08F8-966D-4A38-A9FF-F0B3FB3335BE}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "ConnectionInterception", "Miscellaneous\ConnectionInterception\ConnectionInterception.csproj", "{1CE06110-E69A-44BD-ACBE-D7F96B02288B}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "ConnectionInterception", "Miscellaneous\ConnectionInterception\ConnectionInterception.csproj", "{1CE06110-E69A-44BD-ACBE-D7F96B02288B}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "SaveChangesInterception", "Miscellaneous\SaveChangesInterception\SaveChangesInterception.csproj", "{8F5C3F05-BD4B-4ED3-BCE4-45CA738C2AD3}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "SaveChangesInterception", "Miscellaneous\SaveChangesInterception\SaveChangesInterception.csproj", "{8F5C3F05-BD4B-4ED3-BCE4-45CA738C2AD3}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "CachingInterception", "Miscellaneous\CachingInterception\CachingInterception.csproj", "{DCF56A96-123F-48A6-A848-2BAE19B58C79}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "CachingInterception", "Miscellaneous\CachingInterception\CachingInterception.csproj", "{DCF56A96-123F-48A6-A848-2BAE19B58C79}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "CommandInterception", "Miscellaneous\CommandInterception\CommandInterception.csproj", "{97BECA9A-A72B-4C77-ADDB-DCC84966570F}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "CommandInterception", "Miscellaneous\CommandInterception\CommandInterception.csproj", "{97BECA9A-A72B-4C77-ADDB-DCC84966570F}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "Events", "Miscellaneous\Events\Events.csproj", "{8138D0F5-D1A7-4908-8A52-08196FF46B69}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Events", "Miscellaneous\Events\Events.csproj", "{8138D0F5-D1A7-4908-8A52-08196FF46B69}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "DiagnosticListeners", "Miscellaneous\DiagnosticListeners\DiagnosticListeners.csproj", "{AF719729-AED8-4DEB-B895-61D8EBB50A01}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "DiagnosticListeners", "Miscellaneous\DiagnosticListeners\DiagnosticListeners.csproj", "{AF719729-AED8-4DEB-B895-61D8EBB50A01}" EndProject -Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "ConfiguringDbContext", "Miscellaneous\ConfiguringDbContext\ConfiguringDbContext.csproj", "{73503DF2-CD85-4710-BE94-B83B87054709}" +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "ConfiguringDbContext", "Miscellaneous\ConfiguringDbContext\ConfiguringDbContext.csproj", "{73503DF2-CD85-4710-BE94-B83B87054709}" +EndProject +Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "UserDefinedFunctionMapping", "Querying\UserDefinedFunctionMapping\UserDefinedFunctionMapping.csproj", "{11AB574E-5DA9-4C37-A342-41B3DB5D7C0D}" EndProject Global GlobalSection(SolutionConfigurationPlatforms) = preSolution @@ -345,6 +347,10 @@ Global {73503DF2-CD85-4710-BE94-B83B87054709}.Debug|Any CPU.Build.0 = Debug|Any CPU {73503DF2-CD85-4710-BE94-B83B87054709}.Release|Any CPU.ActiveCfg = Release|Any CPU {73503DF2-CD85-4710-BE94-B83B87054709}.Release|Any CPU.Build.0 = Release|Any CPU + {11AB574E-5DA9-4C37-A342-41B3DB5D7C0D}.Debug|Any CPU.ActiveCfg = Debug|Any CPU + {11AB574E-5DA9-4C37-A342-41B3DB5D7C0D}.Debug|Any CPU.Build.0 = Debug|Any CPU + {11AB574E-5DA9-4C37-A342-41B3DB5D7C0D}.Release|Any CPU.ActiveCfg = Release|Any CPU + {11AB574E-5DA9-4C37-A342-41B3DB5D7C0D}.Release|Any CPU.Build.0 = Release|Any CPU EndGlobalSection GlobalSection(SolutionProperties) = preSolution HideSolutionNode = FALSE @@ -399,6 +405,7 @@ Global {8138D0F5-D1A7-4908-8A52-08196FF46B69} = {85AFD7F1-6943-40FE-B8EC-AA9DBB42CCA6} {AF719729-AED8-4DEB-B895-61D8EBB50A01} = {85AFD7F1-6943-40FE-B8EC-AA9DBB42CCA6} {73503DF2-CD85-4710-BE94-B83B87054709} = {85AFD7F1-6943-40FE-B8EC-AA9DBB42CCA6} + {11AB574E-5DA9-4C37-A342-41B3DB5D7C0D} = {1AD64707-0BE0-48B0-A803-916FF96DCB4F} EndGlobalSection GlobalSection(ExtensibilityGlobals) = postSolution SolutionGuid = {20C98D35-54EF-46A6-8F3B-1855C1AE4F70}