SQL Query Guidelines
This document describes various guidelines to follow when writing SQL queries, either using ActiveRecord/Arel or raw SQL queries.
LIKE
Statements
Using The most common way to search for data is using the LIKE
statement. For
example, to get all issues with a title starting with "Draft:" you'd write the
following query:
SELECT *
FROM issues
WHERE title LIKE 'Draft:%';
On PostgreSQL the LIKE
statement is case-sensitive. To perform a case-insensitive
LIKE
you have to use ILIKE
instead.
To handle this automatically you should use LIKE
queries using Arel instead
of raw SQL fragments, as Arel automatically uses ILIKE
on PostgreSQL.
Issue.where('title LIKE ?', 'Draft:%')
You'd write this instead:
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
Here matches
generates the correct LIKE
/ ILIKE
statement depending on the
database being used.
If you need to chain multiple OR
conditions you can also do this using Arel:
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
On PostgreSQL, this produces:
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
LIKE
& Indexes
PostgreSQL does not use any indexes when using LIKE
/ ILIKE
with a wildcard at
the start. For example, this does not use any indexes:
SELECT *
FROM issues
WHERE title ILIKE '%Draft:%';
Because the value for ILIKE
starts with a wildcard the database is not able to
use an index as it doesn't know where to start scanning the indexes.
Luckily, PostgreSQL does provide a solution: trigram Generalized Inverted Index (GIN) indexes. These indexes can be created as follows:
CREATE INDEX [CONCURRENTLY] index_name_here
ON table_name
USING GIN(column_name gin_trgm_ops);
The key here is the GIN(column_name gin_trgm_ops)
part. This creates a
GIN index
with the operator class set to gin_trgm_ops
. These indexes
can be used by ILIKE
/ LIKE
and can lead to greatly improved performance.
One downside of these indexes is that they can easily get quite large (depending
on the amount of data indexed).
To keep naming of these indexes consistent, use the following naming pattern:
index_TABLE_on_COLUMN_trigram
For example, a GIN/trigram index for issues.title
would be called
index_issues_on_title_trigram
.
Due to these indexes taking quite some time to be built they should be built
concurrently. This can be done by using CREATE INDEX CONCURRENTLY
instead of
just CREATE INDEX
. Concurrent indexes can not be created inside a
transaction. Transactions for migrations can be disabled using the following
pattern:
class MigrationName < Gitlab::Database::Migration[2.1]
disable_ddl_transaction!
end
For example:
class AddUsersLowerUsernameEmailIndexes < Gitlab::Database::Migration[2.1]
disable_ddl_transaction!
def up
execute 'CREATE INDEX CONCURRENTLY index_on_users_lower_username ON users (LOWER(username));'
execute 'CREATE INDEX CONCURRENTLY index_on_users_lower_email ON users (LOWER(email));'
end
def down
remove_index :users, :index_on_users_lower_username
remove_index :users, :index_on_users_lower_email
end
end
Reliably referencing database columns
ActiveRecord by default returns all columns from the queried database table. In some cases the returned rows might need to be customized, for example:
- Specify only a few columns to reduce the amount of data returned from the database.
- Include columns from
JOIN
relations. - Perform calculations (
SUM
,COUNT
).
In this example we specify the columns, but not their tables:
-
path
from theprojects
table -
user_id
from themerge_requests
table
The query:
Issue.where('title LIKE ?', 'Draft:%')
```0
Later on, a new feature adds an extra column to the `projects` table: `user_id`. During deployment there might be a short time window where the database migration is already executed, but the new version of the application code is not deployed yet. When the query mentioned above executes during this period, the query fails with the following error message: `PG::AmbiguousColumn: ERROR: column reference "user_id" is ambiguous`
The problem is caused by the way the attributes are selected from the database. The `user_id` column is present in both the `users` and `merge_requests` tables. The query planner cannot decide which table to use when looking up the `user_id` column.
When writing a customized `SELECT` statement, it's better to **explicitly specify the columns with the table name**.
### Good (prefer)
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```1
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```2
Example using Arel (`arel_table`):
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```3
When writing raw SQL query:
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```4
When the raw SQL query is parameterized (needs escaping):
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```5
### Bad (avoid)
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```6
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```7
When a column list is given, ActiveRecord tries to match the arguments against the columns defined in the `projects` table and prepend the table name automatically. In this case, the `id` column is not a problem, but the `user_id` column could return unexpected data:
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```8
## Plucking IDs
Be very careful using ActiveRecord's `pluck` to load a set of values into memory only to
use them as an argument for another query. In general, moving query logic out of PostgreSQL
and into Ruby is detrimental because PostgreSQL has a query optimizer that performs better
when it has relatively more context about the desired operation.
If, for some reason, you need to `pluck` and use the results in a *single* query then,
most likely, a materialized CTE will be a better choice:
```ruby
Issue.where('title LIKE ?', 'Draft:%')
```9
which will make PostgreSQL pluck the values into an internal array.
Some pluck-related mistakes that you should avoid:
- Passing too many integers into a query. While not explicitly limited, PostgreSQL has a
practical arity limit of a couple thousand IDs. We don't want to run up against this limit.
- Generating gigantic query text that can cause problems for our logging infrastructure.
- Accidentally scanning an entire table. For example, this executes an
extra unnecessary database query and load a lot of unnecessary data into memory:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```0
Instead you can just use sub-queries which perform far better:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```1
A few specific reasons you might choose `pluck`:
- You actually need to operate on the values in Ruby itself. For example, writing them to a file.
- The values get cached or memoized in order to be reused in **multiple related queries**.
In line with our `CodeReuse/ActiveRecord` cop, you should only use forms like
`pluck(:id)` or `pluck(:user_id)` within model code. In the former case, you can
use the `ApplicationRecord`-provided `.pluck_primary_key` helper method instead.
In the latter, you should add a small helper method to the relevant model.
If you have strong reasons to use `pluck`, it could make sense to limit the number
of records plucked. `MAX_PLUCK` defaults to `1_000` in `ApplicationRecord`. In all cases,
you should still consider using a subquery and make sure that using `pluck` is a reliably
better option.
## Inherit from ApplicationRecord
Most models in the GitLab codebase should inherit from `ApplicationRecord`
or `Ci::ApplicationRecord` rather than from `ActiveRecord::Base`. This allows
helper methods to be easily added.
An exception to this rule exists for models created in database migrations. As
these should be isolated from application code, they should continue to subclass
from `MigrationRecord` which is available only in migration context.
## Use UNIONs
`UNION`s aren't very commonly used in most Rails applications but they're very
powerful and useful. Queries tend to use a lot of `JOIN`s to
get related data or data based on certain criteria, but `JOIN` performance can
quickly deteriorate as the data involved grows.
For example, if you want to get a list of projects where the name contains a
value _or_ the name of the namespace contains a value most people would write
the following query:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```2
Using a large database this query can easily take around 800 milliseconds to
run. Using a `UNION` we'd write the following instead:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```3
This query in turn only takes around 15 milliseconds to complete while returning
the exact same records.
This doesn't mean you should start using UNIONs everywhere, but it's something
to keep in mind when using lots of JOINs in a query and filtering out records
based on the joined data.
GitLab comes with a `Gitlab::SQL::Union` class that can be used to build a `UNION`
of multiple `ActiveRecord::Relation` objects. You can use this class as
follows:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```4
The `FromUnion` model concern provides a more convenient method to produce the same result as above:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```5
`UNION` is common through the codebase, but it's also possible to use the other SQL set operators of `EXCEPT` and `INTERSECT`:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```6
### Uneven columns in the `UNION` sub-queries
When the `UNION` query has uneven columns in the `SELECT` clauses, the database returns an error.
Consider the following `UNION` query:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```7
The query results in the following error message:
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```8
This problem is apparent and it can be easily fixed during development. One edge-case is when
`UNION` queries are combined with explicit column listing where the list comes from the
`ActiveRecord` schema cache.
Example (bad, avoid it):
```ruby
Issue.where(Issue.arel_table[:title].matches('Draft:%'))
```9
When this code is deployed, it doesn't cause problems immediately. When another
developer adds a new database column to the `users` table, this query breaks in
production and can cause downtime. The second query (`SELECT users.*`) includes the
newly added column; however, the first query does not. The `column_names` method returns stale
values (the new column is missing), because the values are cached within the `ActiveRecord` schema
cache. These values are usually populated when the application boots up.
At this point, the only fix would be a full application restart so that the schema cache gets
updated. Since [GitLab 16.1](https://gitlab.com/gitlab-org/gitlab/-/merge_requests/121957),
the schema cache will be automatically reset so that subsequent queries
will succeed. This reset can be disabled by disabling the `ops` feature
flag `reset_column_information_on_statement_invalid`.
The problem can be avoided if we always use `SELECT users.*` or we always explicitly define the
columns.
Using `SELECT users.*`:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```0
Explicit column list definition:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```1
## Ordering by Creation Date
When ordering records based on the time they were created, you can order
by the `id` column instead of ordering by `created_at`. Because IDs are always
unique and incremented in the order that rows are created, doing so produces the
exact same results. This also means there's no need to add an index on
`created_at` to ensure consistent performance as `id` is already indexed by
default.
## Use `WHERE EXISTS` instead of `WHERE IN`
While `WHERE IN` and `WHERE EXISTS` can be used to produce the same data it is
recommended to use `WHERE EXISTS` whenever possible. While in many cases
PostgreSQL can optimize `WHERE IN` quite well there are also many cases where
`WHERE EXISTS` performs (much) better.
In Rails you have to use this by creating SQL fragments:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```2
This would then produce a query along the lines of the following:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```3
## Query plan flip problem with `.exists?` queries
In Rails, calling `.exists?` on an ActiveRecord scope could cause query plan flip issues, which
could lead to database statement timeouts. When preparing query plans for review, it's advisable to
check all variants of the underlying query form ActiveRecord scopes.
Example: check if there are any epics in the group and its subgroups.
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```4
When the `.exists?` method is called, Rails modifies the active record scope:
- Replaces the select columns with `SELECT 1`.
- Adds `LIMIT 1` to the query.
When invoked, complex ActiveRecord scopes, such as those with `IN` queries, could negatively alter database query planning behavior.
Execution plan:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```5
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```6
Notice the `Index Only Scan` on the `index_epics_on_group_id_and_iid` index where the planner estimates reading more than 400,000 rows.
If we execute the query without `exists?`, we get a different execution plan:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```7
Execution plan:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```8
This query plan doesn't contain the `MATERIALIZE` nodes and uses a more efficient access method by loading the group
hierarchy first.
Query plan flips can be accidentally introduced by even the smallest query change. Revisiting the `.exists?` query where selecting
the group ID database column differently:
```ruby
table = Issue.arel_table
Issue.where(table[:title].matches('Draft:%').or(table[:foo].matches('Draft:%')))
```9
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```0
Here we see again the better execution plan. In case we do a small change to the query, it flips again:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```1
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```2
Forcing an execution plan is possible if the `IN` subquery is moved to a CTE:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```3
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```4
NOTE:
Due to their complexity, using CTEs should be the last resort. Use CTEs only when simpler query changes don't produce a favorable execution plan.
## `.find_or_create_by` is not atomic
The inherent pattern with methods like `.find_or_create_by` and
`.first_or_create` and others is that they are not atomic. This means,
it first runs a `SELECT`, and if there are no results an `INSERT` is
performed. With concurrent processes in mind, there is a race condition
which may lead to trying to insert two similar records. This may not be
desired, or may cause one of the queries to fail due to a constraint
violation, for example.
Using transactions does not solve this problem.
To solve this we've added the `ApplicationRecord.safe_find_or_create_by`.
This method can be used the same way as
`find_or_create_by`, but it wraps the call in a *new* transaction (or a subtransaction) and
retries if it were to fail because of an
`ActiveRecord::RecordNotUnique` error.
To be able to use this method, make sure the model you want to use
this on inherits from `ApplicationRecord`.
In Rails 6 and later, there is a
[`.create_or_find_by`](https://api.rubyonrails.org/classes/ActiveRecord/Relation.html#method-i-create_or_find_by)
method. This method differs from our `.safe_find_or_create_by` methods
because it performs the `INSERT`, and then performs the `SELECT` commands only if that call
fails.
If the `INSERT` fails, it leaves a dead tuple around and
increment the primary key sequence (if any), among [other downsides](https://api.rubyonrails.org/classes/ActiveRecord/Relation.html#method-i-create_or_find_by).
We prefer `.safe_find_or_create_by` if the common path is that we
have a single record which is reused after it has first been created.
However, if the more common path is to create a new record, and we only
want to avoid duplicate records to be inserted on edge cases
(for example a job-retry), then `.create_or_find_by` can save us a `SELECT`.
Both methods use subtransactions internally if executed within the context of
an existing transaction. This can significantly impact overall performance,
especially if more than 64 live subtransactions are being used inside a single transaction.
### Can I use `.safe_find_or_create_by`?
If your code is generally isolated (for example it's executed in a worker only) and not wrapped with another transaction, then you can use `.safe_find_or_create_by`. However, there is no tooling to catch cases when someone else calls your code within a transaction. Using `.safe_find_or_create_by` will definitely carry some risks that cannot be eliminated completely at the moment.
Additionally, we have a RuboCop rule `Performance/ActiveRecordSubtransactionMethods` that prevents the usage of `.safe_find_or_create_by`. This rule can be disabled on a case by case basis via `# rubocop:disable Performance/ActiveRecordSubtransactionMethods`.
### Alternatives to .find_or_create_by
#### Alternative 1: `UPSERT`
The [`.upsert`](https://api.rubyonrails.org/v7.0.5/classes/ActiveRecord/Persistence/ClassMethods.html#method-i-upsert) method can be an alternative solution when the table is backed by a unique index.
Simple usage of the `.upsert` method:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```5
A few things to be careful about:
- The sequence for the primary key will be incremented, even if the record was only updated.
- The created record is not returned. The `returning` option only returns data when an `INSERT` happens (new record).
- `ActiveRecord` validations are not executed.
An example of the `.upsert` method with validations and record loading:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```6
The code snippet above will not work well if there is a model-level uniqueness validation on the `build_id` column because we invoke the validation before calling `.upsert`.
To work around this, we have two options:
- Remove the uniqueness validation from the `ActiveRecord` model.
- Use the [`on` keyword](https://guides.rubyonrails.org/active_record_validations.html#on) and implement context-specific validation.
#### Alternative 2: Check existence and rescue
When the chance of concurrently creating the same record is very low, we can use a simpler approach:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```7
The method does the following:
1. Look up the model by the unique column.
1. If no record found, build a new one.
1. Persist the record.
There is a short race condition between the lookup query and the persist query where another process could insert the record and cause an `ActiveRecord::RecordInvalid` exception.
The code rescues this particular exception and retries the operation. For the second run, the record would be successfully located. For example check [this block of code](https://gitlab.com/gitlab-org/gitlab/-/blob/0b51d7fbb97d4becf5fd40bc3b92f732bece85bd/ee/app/services/compliance_management/standards/gitlab/prevent_approval_by_author_service.rb#L20-30) in `PreventApprovalByAuthorService`.
## Monitor SQL queries in production
GitLab team members can monitor slow or canceled queries on GitLab.com
using the PostgreSQL logs, which are indexed in Elasticsearch and
searchable using Kibana.
See [the runbook](https://gitlab.com/gitlab-com/runbooks/-/blob/master/docs/patroni/pg_collect_query_data.md#searching-postgresql-logs-with-kibanaelasticsearch)
for more details.
## When to use common table expressions
You can use common table expressions (CTEs) to create a temporary result set within a more complex query.
You can also use a recursive CTE to reference the CTE's result set within
the query itself. The following example queries a chain of
`personal access tokens` referencing each other in the
`previous_personal_access_token_id` column.
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```8
As CTEs are temporary result sets, you can use them within another `SELECT`
statement. Using CTEs with `UPDATE`, or `DELETE` could lead to unexpected
behavior:
Consider the following method:
```sql
SELECT *
FROM issues
WHERE (title ILIKE 'Draft:%' OR foo ILIKE 'Draft:%')
```9
It works as expected when it is used to query data:
```sql
SELECT *
FROM issues
WHERE title ILIKE '%Draft:%';
```0
However, the CTE is dropped when used with `#update_all`. As a result, the method
updates the entire table:
```sql
SELECT *
FROM issues
WHERE title ILIKE '%Draft:%';
```1
To work around this behavior:
1. Query the `ids` of the records:
```ruby
> token_ids = personal_access_token_chain(token).pluck_primary_key
=> [16, 17, 18, 19, 20, 21]
-
Use this array to scope
PersonalAccessTokens
:PersonalAccessToken.where(id: token_ids).update_all(revoked: true)
Alternatively, combine these two steps:
SELECT *
FROM issues
WHERE title ILIKE '%Draft:%';
```2
NOTE:
Avoid updating large volumes of unbounded data. If there are no [application limits](application_limits.md) on the data, or you are unsure about the data volume, you should [update the data in batches](database/iterating_tables_in_batches.md).