Skip to content

Commit

Permalink
Document good pagination practices
Browse files Browse the repository at this point in the history
  • Loading branch information
roji committed Dec 19, 2021
1 parent 4b71734 commit 9a52618
Show file tree
Hide file tree
Showing 7 changed files with 174 additions and 0 deletions.
6 changes: 6 additions & 0 deletions entity-framework/core/performance/efficient-querying.md
Original file line number Diff line number Diff line change
Expand Up @@ -183,6 +183,12 @@ Here are the results for a benchmark comparing tracking vs. no-tracking behavior

Finally, it is possible to perform updates without the overhead of change tracking, by utilizing a no-tracking query and then attaching the returned instance to the context, specifying which changes are to be made. This transfers the burden of change tracking from EF to the user, and should only be attempted if the change tracking overhead has been shown to be unacceptable via profiling or benchmarking.

## Efficient pagination

Pagination refers to retrieving results in pages, rather than all at once; this is typically done for large resultsets, where a user interface is shown that allows the user to navigate to the next or previous page of the results. A common way to implement pagination with databases is to use the `Skip` and `Take` (`OFFSET` and `LIMIT` in SQL); while this is an intuitive implementation, it's also quite inefficient. For pagination that allows moving on page at a time (as opposed to jumping to arbitrary pages), consider using `keyset pagination` instead.

[See the documentation page on pagination](xref:core/querying/pagination) for more information.

## Using raw SQL

In some cases, more optimized SQL exists for your query, which EF does not generate. This can happen when the SQL construct is an extension specific to your database that's unsupported, or simply because EF does not translate to it yet. In these cases, writing SQL by hand can provide a substantial performance boost, and EF supports several ways to do this.
Expand Down
56 changes: 56 additions & 0 deletions entity-framework/core/querying/pagination.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
---
title: Pagination - EF Core
description: Writing paginating queries in Entity Framework Core
author: roji
ms.date: 12/19/2021
uid: core/querying/pagination
---
# Pagination

Pagination refers to retrieving results in pages, rather than all at once; this is typically done for large resultsets, where a user interface is shown that allows the user to navigate to the next or previous page of the results.

## Offset pagination

A common way to implement pagination with databases is to use the `Skip` and `Take` (`OFFSET` and `LIMIT` in SQL). Given a a page size of 10 results, the third page can be fetched with EF Core as follows:

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

Unfortunately, while this technique is very intuitive, it also has some severe shortcomings:

1. The database must still process the first 20 entries, even if they aren't returned to the application; this creates possibly significant computation load that increases with the number of rows being skipped.
2. If any updates occur concurrently, your pagination may end up skipping certain entries or showing them twice. For example, if an entry is removed as the user is moving from page 2 to 3, the whole resultset "shifts up", and one entry would be skipped.

## Keyset pagination

The recommended alternative to offset-based pagination - sometimes called *keyset pagination* or *seek-based pagination* - is simply use a `WHERE` clause to skip rows, instead of an offset. This means remember the relevant values from the last entry fetched (instead of its offset), and to ask for the next rows after that row. For example, assuming the last entry in the last page we fetched had an ID value of 55, we'd simply do the following:

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

Assuming an index is defined on `PostId`, this query is very efficient, and also isn't sensitive to any concurrent changes happening in lower Id values.

Keyset pagination is appropriate for pagination interfaces where the user navigates forwards and backwards, but does not support random access, where the user can jump to any specific page. Random access pagination requires using offset pagination as explained above; because of the shortcomings of offset pagination, carefully consider if random access pagination really is required for your use case, or if next/previous page navigation is enough. If random access pagination is necessary, a robust implementation could use keyset pagination when navigation to the next/previous page, and offset navigation when jumping to any other page.

> [!WARNING]
> Always make sure that your ordering is fully deterministic. For example, if results are ordered only by date, but there can be multiple results with the same date, then results could be skipped when paginating as they're ordered differently across two queries. Ordering by both date and ID (or any other unique property) makes the resultset deterministic and avoids this problem. Note that relational database do not apply any ordering by default, even on the primary key; queries without explicit ordering have non-deterministic resultsets.
### Multiple pagination keys

When using keyset pagination, it's frequently necessary to order by more than one property. For example, the following query paginates by date and ID:

[!code-csharp[Main](../../../samples/core/Querying/Pagination/Program.cs?name=KeySetPaginationWithMultipleKeys&highlight=6)]

This ensures that the next page picks off exactly where the previous one ended. As more ordering keys are added, additional clauses can be added.

> [!NOTE]
> Most SQL databases support a simpler and more efficient version of the above, using *row values*: `WHERE (Date, Id) > (@lastDate, @lastId)`. EF Core does not currently support expressing this in LINQ queries, this is tracked by [#26822](https://github.com/dotnet/efcore/issues/26822).
## Indexes

As with any other query, proper indexing is vital for good performance: make sure to have indexes in place which correspond to your pagination ordering. If ordering by more than one column, an index over those multiple columns can be defined; this is called a *composite index*.

For more information, [see the documentation page on indexes](xref:core/modeling/indexes).

## Additional resources

* To learn more about the shortcomings of offset-based pagination and about keyset pagination, [see this post](https://use-the-index-luke.com/no-offset).
* [A technical deep dive presentation](https://www.slideshare.net/MarkusWinand/p2d2-pagination-done-the-postgresql-way) on offset-based and
2 changes: 2 additions & 0 deletions entity-framework/toc.yml
Original file line number Diff line number Diff line change
Expand Up @@ -212,6 +212,8 @@
href: core/querying/single-split-queries.md
- name: Complex query operators
href: core/querying/complex-query-operators.md
- name: Pagination
href: core/querying/pagination.md
- name: Raw SQL queries
href: core/querying/raw-sql.md
- name: Database functions
Expand Down
46 changes: 46 additions & 0 deletions samples/core/Querying/Pagination/BloggingContext.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
using System;
using System.Collections.Generic;
using Microsoft.EntityFrameworkCore;
using Microsoft.Extensions.Logging;

namespace EFQuerying.Pagination
{
public class BloggingContext : DbContext
{
public DbSet<Blog> Blogs { get; set; }
public DbSet<Post> Posts { get; set; }

#region SimpleLogging
protected override void OnConfiguring(DbContextOptionsBuilder optionsBuilder)
{
optionsBuilder
.UseSqlServer(@"Server=(localdb)\mssqllocaldb;Database=Blogging;Trusted_Connection=True")
.LogTo(Console.WriteLine, LogLevel.Information);
}
#endregion

protected override void OnModelCreating(ModelBuilder modelBuilder)
{
modelBuilder.Entity<Post>().HasIndex(p => p.Title);
}
}

public class Blog
{
public int BlogId { get; set; }
public string Url { get; set; }
public int Rating { get; set; }
public List<Post> Posts { get; set; }
}

public class Post
{
public int PostId { get; set; }
public string Title { get; set; }
public string Content { get; set; }
public DateTime Date { get; set; }

public int BlogId { get; set; }
public Blog Blog { get; set; }
}
}
15 changes: 15 additions & 0 deletions samples/core/Querying/Pagination/Pagination.csproj
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
<Project Sdk="Microsoft.NET.Sdk">

<PropertyGroup>
<OutputType>Exe</OutputType>
<TargetFramework>net6.0</TargetFramework>
<RootNamespace>EFQuerying.Pagination</RootNamespace>
<AssemblyName>EFQuerying.Pagination</AssemblyName>
</PropertyGroup>

<ItemGroup>
<PackageReference Include="Microsoft.EntityFrameworkCore.SqlServer" Version="6.0.0" />
<PackageReference Include="Microsoft.EntityFrameworkCore.Sqlite" Version="6.0.0" />
</ItemGroup>

</Project>
42 changes: 42 additions & 0 deletions samples/core/Querying/Pagination/Program.cs
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
using System;
using System.Linq;
using Microsoft.EntityFrameworkCore;

namespace EFQuerying.Pagination
{
internal class Program
{
private static void Main(string[] args)
{
using (var context = new BloggingContext())
{
#region OffsetPagination
var position = 20;
var nextPage = context.Posts.OrderBy(b => b.PostId).Skip(position).Take(10).ToList();
#endregion
}

using (var context = new BloggingContext())
{
#region KeySetPagination
var lastId = 55;
var nextPage = context.Posts.OrderBy(b => b.PostId).Where(b => b.PostId > lastId).Take(10).ToList();
#endregion
}

using (var context = new BloggingContext())
{
#region KeySetPaginationWithMultipleKeys
var lastDate = new DateTime(2020, 1, 1);
var lastId = 55;
var nextPage = context.Posts
.OrderBy(b => b.Date)
.ThenBy(b => b.PostId)
.Where(b => b.Date > lastDate || (b.Date == lastDate && b.PostId > lastId))
.Take(10)
.ToList();
#endregion
}
}
}
}
7 changes: 7 additions & 0 deletions samples/core/Samples.sln
Original file line number Diff line number Diff line change
Expand Up @@ -177,6 +177,8 @@ Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "Misc", "Modeling\Misc\Misc.
EndProject
Project("{9A19103F-16F7-4668-BE54-9A1E7A4F7556}") = "BulkConfiguration", "Modeling\BulkConfiguration\BulkConfiguration.csproj", "{FE7AB616-97A5-46D4-A8B1-B2980A8C7379}"
EndProject
Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "Pagination", "Querying\Pagination\Pagination.csproj", "{A7A02F2B-36E1-46A5-AF1F-E58E99E73324}"
EndProject
Global
GlobalSection(SolutionConfigurationPlatforms) = preSolution
Debug|Any CPU = Debug|Any CPU
Expand Down Expand Up @@ -491,6 +493,10 @@ Global
{FE7AB616-97A5-46D4-A8B1-B2980A8C7379}.Debug|Any CPU.Build.0 = Debug|Any CPU
{FE7AB616-97A5-46D4-A8B1-B2980A8C7379}.Release|Any CPU.ActiveCfg = Release|Any CPU
{FE7AB616-97A5-46D4-A8B1-B2980A8C7379}.Release|Any CPU.Build.0 = Release|Any CPU
{A7A02F2B-36E1-46A5-AF1F-E58E99E73324}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
{A7A02F2B-36E1-46A5-AF1F-E58E99E73324}.Debug|Any CPU.Build.0 = Debug|Any CPU
{A7A02F2B-36E1-46A5-AF1F-E58E99E73324}.Release|Any CPU.ActiveCfg = Release|Any CPU
{A7A02F2B-36E1-46A5-AF1F-E58E99E73324}.Release|Any CPU.Build.0 = Release|Any CPU
EndGlobalSection
GlobalSection(SolutionProperties) = preSolution
HideSolutionNode = FALSE
Expand Down Expand Up @@ -568,6 +574,7 @@ Global
{06539D34-C8D3-4868-A925-C3FCB3C7EE1E} = {CA5046EC-C894-4535-8190-A31F75FDEB96}
{8A45191D-F719-4CFB-AB37-7A1653BCC720} = {CA5046EC-C894-4535-8190-A31F75FDEB96}
{FE7AB616-97A5-46D4-A8B1-B2980A8C7379} = {CA5046EC-C894-4535-8190-A31F75FDEB96}
{A7A02F2B-36E1-46A5-AF1F-E58E99E73324} = {1AD64707-0BE0-48B0-A803-916FF96DCB4F}
EndGlobalSection
GlobalSection(ExtensibilityGlobals) = postSolution
SolutionGuid = {20C98D35-54EF-46A6-8F3B-1855C1AE4F70}
Expand Down

0 comments on commit 9a52618

Please sign in to comment.