AbsintheRelayKeysetConnection (absinthe_relay_keyset_connection v2.1.0)
View SourceSupport for paginated result sets using keyset pagination, for use in an Absinthe resolver module. Requires defining a connection with Absinthe.Relay.Connection.
The TL;DR
In a resolver...
AbsintheRelayKeysetConnection.from_query(
ecto_users_query,
&MyRepo.all/1,
%{
sorts: [%{name: :desc}, %{id: :desc}],
first: 10,
after: "0QTwn5SRWyJNbyIsMjZd"
},
%{
unique_column: :id
}
)
Details
Why keyset pagination?
By default,
Absinthe.Relay.Connection
uses offset-based pagination.
For example, with a page size of 10, it would get the first page of records
with a SQL query like OFFSET 0 LIMIT 10
, the second page with OFFSET 10 LIMIT 10
, and so on.
This works well for many use cases and requires no knowledge of the
underlying database schema.
However, when the value of OFFSET
is large, it can cause poor database
performance.
(A "large" offset depends on your data; it might be in the millions before you notice a performance hit.)
Keyset pagination means that, in the example above, the first page might be
fetched with WHERE id > 0 ORDER BY id ASC LIMIT 10
.
If the last record on that page had id 10
, the query for the next page could be
fetched with WHERE id > 10 ORDER BY id ASC LIMIT 10
.
This WHERE
clause lets the database efficiently ignore earlier records,
especially if the id
column is indexed.
The cursor
With offset-based pagination, a user needs only to say "I want 10 records per
page, and give me page 3, please."
We can easily calculate the offset as (page_number - 1) * limit
.
But for keyset-based pagination, we need more information.
To get the next page, we need to know which record appeared last on the page
the user just got; for example, if it was record 10, we will query WHERE id > 10
.
The user needs to supply this information using a "cursor".
In this simple case, the cursor need contain only the id.
(Typically this value is encoded in a way that makes it opaque to the user in
order to indicate that it's an implementation detail.)
But sorting and the need for uniqueness add some complexity to the picture.
Sorting and uniqueness
Keyset pagination only works if our sorting (eg ORDER BY id asc
and
comparison (eg WHERE id > 10
) agree and are based on a unique, sortable
column or combination of columns.
(In database terms, any attribute or list of attributes which uniquely identify
a row is a "key"; this likely is the basis of the term "keyset pagination".)
Imagine trying to use a non-unique column like last_name
.
If the last person on the current page is Abe Able
, requesting the next
page with WHERE last_name > 'Able'
will accidentally skip Beth Able
, who should
have appeared on the next page.
To avoid this, we need to ensure that we order by a unique combination of
columns - such as ORDER BY last_name ASC, id ASC
- and use the same columns for the
WHERE
- such as WHERE last_name > 'Able' OR (last_name = 'Able' AND id > 10)
.
If your table has a unique column like id
, from_query/4
can automatically
add it to the ORDER BY
and WHERE
clauses of queries which don't already
use it; just indicate which column to use in the config
argument.
It's also problematic if the columns are not meaningfully ordered. If you're
paging through records and request WHERE id > 100
, a new record inserted
with id 105
will show up in your results.
But if you're using WHERE uuid > $some_uuid
, it might not.
Note that since the cursor is the basis of the WHERE
clause, whatever
columns the query is being ordered by are included in the cursor value (which
is opaque to users).
In the example above, the cursor for each record would include the last name
and id.
Serialization
As explained above, building the cursor involves serializing the columns
which are used in the ORDER BY
so that they can also be used in the
WHERE
.
For example, if ordering users by name and id, the cursor for each user
record will contain that user's name and id.
You can provide your own AbsintheRelayKeysetConnection.CursorTranslator
to customize
the serialization and deserialization of your cursors, or use the built-in
AbsintheRelayKeysetConnection.CursorTranslator.Base64Hashed
.
Handling NULL Values
By default, NULL values in sortable columns can cause pagination to fail because
SQL comparisons with NULL (like WHERE name > NULL
) are unsafe and forbidden by Ecto.
To handle this, you can use the :null_coalesce
configuration option to specify
replacement values for NULL columns during sorting and cursor operations.
Example with NULL Coalescing
# Without null coalescing - crashes if cursors contain NULL values
AbsintheRelayKeysetConnection.from_query(
User,
&MyRepo.all/1,
%{sorts: [%{last_name: :asc}], first: 10},
%{unique_column: :id}
)
# With null coalescing - NULL values are treated as empty strings
AbsintheRelayKeysetConnection.from_query(
User,
&MyRepo.all/1,
%{sorts: [%{last_name: :asc}], first: 10},
%{
unique_column: :id,
null_coalesce: %{last_name: ""}
}
)
How NULL Coalescing Works
When you configure null_coalesce: %{last_name: ""}
:
- SQL Sorting: Uses
ORDER BY COALESCE(last_name, '')
- NULL values sort as empty strings - Cursor Encoding: NULL values are encoded as the coalesce value in cursors
- WHERE Clauses: Uses
WHERE COALESCE(last_name, '') > 'value'
for safe comparisons
Per-Column Configuration
You can specify different coalesce values for different columns:
%{
null_coalesce: %{
last_name: "", # NULL last names become empty string
first_name: "Unknown", # NULL first names become "Unknown"
score: 0 # NULL scores become 0
}
}
This ensures consistent, predictable sorting behavior regardless of NULL values in your data.
Cautions
There are a few things you can't do with this pagination style.
First, you can't (reliably) paginate records without specifying a unique
column or combination of columns.
For example, if you have an cities
table where the primary key is the
combination of state_id
and city_name
, you'll have to ensure that all
queries include both values in their sorts
.
(It might be simpler to add a sequential integer column and pass that as the
:unique_column
.)
Second, you can't sort by columns on associations. This is not implemented and would be difficult to implement.
Third, you can't paginate at more than one level.
For example, you can't get the first page of authors, get the first page of
posts for each author, and proceed to get subsequent pages of posts for each
author.
Such an access pattern is not a good idea even with OFFSET
pagination; some
authors will have many more pages of posts than others.
But it becomes truly nonsensical to say "for each author, get the first 10
posts with id greater than 10".
Instead of attempting this, it would be better to paginate authors, then separately, paginate posts filtered by author id.
Finally, a caution: since the cursor needs to contain the column values, beware of using large columns in a cursor; they will make the cursor itself large.
Summary
Types
The name of a column to be used in an ORDER BY
clause.
Options that are independent of the current query document.
A wrapper for a single record which includes the record itself (the node) and a cursor that references it.
A single record.
A pagination cursor which is encoded and opaque to users. A cursor represents
the position of a specific record in the pagination set. For example, the
cursor given with post 20
represents that post, so that a user can make a
follow-up request using the same sorts
but specifying the first 10 records
after post 20
, the last 5 records before post 20
, or something similar.
Options derived from the current query document.
Information about the set of records in the current page and how it relates to the overall set of records available for pagination.
A function which can take an Ecto.Queryable()
and use it to fetch records
from a data store.
A common example would be &MyRepo.all/1
.
A single-key map, such as %{name: :asc}
.
Either :asc
or :desc
, to be used in an ORDER BY
clause.
The return value of from_query/4
, representing the paginated data.
Functions
Build a connection from an Ecto Query.
Types
@type column_name() :: atom()
The name of a column to be used in an ORDER BY
clause.
@type config() :: %{ optional(:unique_column) => atom(), optional(:cursor_mod) => module() | nil, optional(:null_coalesce) => %{required(atom()) => term()} }
Options that are independent of the current query document.
@type edge() :: %{node: edge_node(), cursor: encoded_cursor()}
A wrapper for a single record which includes the record itself (the node) and a cursor that references it.
@type edge_node() :: term()
A single record.
@type encoded_cursor() :: binary()
A pagination cursor which is encoded and opaque to users. A cursor represents
the position of a specific record in the pagination set. For example, the
cursor given with post 20
represents that post, so that a user can make a
follow-up request using the same sorts
but specifying the first 10 records
after post 20
, the last 5 records before post 20
, or something similar.
@type options() :: %{ optional(:after) => encoded_cursor(), optional(:before) => encoded_cursor(), optional(:first) => pos_integer(), optional(:last) => pos_integer(), optional(:sorts) => [sort()], optional(any()) => any() }
Options derived from the current query document.
@type page_info() :: %{ start_cursor: encoded_cursor(), end_cursor: encoded_cursor(), has_previous_page: boolean(), has_next_page: boolean() }
Information about the set of records in the current page and how it relates to the overall set of records available for pagination.
@type repo_fun() :: (Ecto.Queryable.t() -> [term()])
A function which can take an Ecto.Queryable()
and use it to fetch records
from a data store.
A common example would be &MyRepo.all/1
.
@type sort() :: %{required(column_name()) => sort_dir()}
A single-key map, such as %{name: :asc}
.
This is the information needed to build a single ORDER BY
clause.
@type sort_dir() :: :asc | :desc
Either :asc
or :desc
, to be used in an ORDER BY
clause.
The return value of from_query/4
, representing the paginated data.
Functions
@spec from_query( queryable :: Ecto.Queryable.t(), repo_fun :: repo_fun(), options :: options(), config :: config() ) :: {:ok, t()} | {:error, String.t()}
Build a connection from an Ecto Query.
This will automatically set an ORDER BY
and WHERE
value based on the
provided options, including the cursor (if one is given), then run the query
with the repo_fun
argument that was given.
Return a single page of results which contains the info specified in the Relay Cursor Connections Specification.
Example
iex> AbsintheRelayKeysetConnection.from_query(
...> ecto_users_query,
...> &MyRepo.all/1,
...> %{
...> sorts: [%{name: :desc}, %{id: :desc}],
...> first: 10,
...> after: "0QTwn5SRWyJNbyIsMjZd"
...> },
...> %{
...> unique_column: :id,
...> null_coalesce: %{name: ""}
...> }
...> )
{:ok, %{
edges: [
%{node: %MyApp.User{id: 11, name: "Jo"}, cursor: "abc123"},
%{node: %MyApp.User{id: 12, name: "Mo"}, cursor: "def345"}
],
page_info: %{
start_cursor: "abc123",
end_cursor: "def345",
has_previous_page: true,
has_next_page: false
}
}}