2012-09-01 17:25:58 -04:00
Active Record Query Interface
=============================
2009-02-03 20:44:58 -05:00
2012-11-29 17:25:02 -05:00
This guide covers different ways to retrieve data from the database using Active Record.
After reading this guide, you will know:
2009-02-03 20:44:58 -05:00
2012-12-07 12:50:09 -05:00
* How to find records using a variety of methods and conditions.
* How to specify the order, retrieved attributes, grouping, and other properties of the found records.
* How to use eager loading to reduce the number of database queries needed for data retrieval.
* How to use dynamic finders methods.
* How to check for the existence of particular records.
* How to perform various calculations on Active Record models.
* How to run EXPLAIN on relations.
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
--------------------------------------------------------------------------------
2009-02-03 20:44:58 -05:00
2011-10-05 17:52:50 -04:00
If you're used to using raw SQL to find database records, then you will generally find that there are better ways to carry out the same operations in Rails. Active Record insulates you from the need to use SQL in most cases.
2009-02-03 20:44:58 -05:00
Code examples throughout this guide will refer to one or more of the following models:
2012-09-01 21:37:59 -04:00
TIP: All of the following models use `id` as the primary key, unless specified otherwise.
2009-02-07 11:05:26 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
class Client < ActiveRecord::Base
has_one :address
has_many :orders
has_and_belongs_to_many :roles
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
class Address < ActiveRecord::Base
belongs_to :client
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
class Order < ActiveRecord::Base
2012-11-15 15:28:24 -05:00
belongs_to :client, counter_cache: true
2009-02-03 20:44:58 -05:00
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
class Role < ActiveRecord::Base
has_and_belongs_to_many :clients
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 11:05:26 -05:00
Active Record will perform queries on the database for you and is compatible with most database systems (MySQL, PostgreSQL and SQLite to name a few). Regardless of which database system you're using, the Active Record method format will always be the same.
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Retrieving Objects from the Database
------------------------------------
2009-02-03 20:44:58 -05:00
2010-06-16 14:06:46 -04:00
To retrieve objects from the database, Active Record provides several finder methods. Each finder method allows you to pass arguments into it to perform certain queries on your database without writing raw SQL.
2010-02-03 18:27:27 -05:00
The methods are:
2012-09-03 21:21:24 -04:00
2012-09-01 21:37:59 -04:00
* `bind`
* `create_with`
2013-06-15 17:10:43 -04:00
* `distinct`
2012-09-01 21:37:59 -04:00
* `eager_load`
* `extending`
* `from`
* `group`
* `having`
* `includes`
* `joins`
* `limit`
* `lock`
* `none`
* `offset`
* `order`
* `preload`
* `readonly`
* `references`
* `reorder`
* `reverse_order`
* `select`
* `uniq`
* `where`
2010-02-03 18:27:27 -05:00
2012-09-01 19:34:21 -04:00
All of the above methods return an instance of `ActiveRecord::Relation` .
2009-02-03 20:44:58 -05:00
2012-09-01 19:34:21 -04:00
The primary operation of `Model.find(options)` can be summarized as:
2009-02-07 11:05:26 -05:00
* Convert the supplied options to an equivalent SQL query.
* Fire the SQL query and retrieve the corresponding results from the database.
* Instantiate the equivalent Ruby object of the appropriate model for every resulting row.
2012-09-01 21:37:59 -04:00
* Run `after_find` callbacks, if any.
2009-02-07 11:05:26 -05:00
2012-09-01 17:25:58 -04:00
### Retrieving a Single Object
2009-02-07 11:05:26 -05:00
2013-05-22 05:17:25 -04:00
Active Record provides several different ways of retrieving a single object.
2009-02-07 11:05:26 -05:00
2012-09-01 17:25:58 -04:00
#### Using a Primary Key
2009-02-07 11:05:26 -05:00
2012-09-01 19:34:21 -04:00
Using `Model.find(primary_key)` , you can retrieve the object corresponding to the specified _primary key_ that matches any supplied options. For example:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 11:05:26 -05:00
# Find the client with primary key (id) 10.
client = Client.find(10)
2011-10-06 16:29:58 -04:00
# => #<Client id: 10, first_name: "Ryan">
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2012-03-05 08:24:34 -05:00
SELECT * FROM clients WHERE (clients.id = 10) LIMIT 1
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
`Model.find(primary_key)` will raise an `ActiveRecord::RecordNotFound` exception if no matching record is found.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
#### `take`
2012-05-05 12:15:09 -04:00
2012-09-01 19:34:21 -04:00
`Model.take` retrieves a record without any implicit ordering. For example:
2012-05-05 12:15:09 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-05 12:15:09 -04:00
client = Client.take
# => #<Client id: 1, first_name: "Lifo">
2012-09-01 17:08:06 -04:00
```
2012-05-05 12:15:09 -04:00
The SQL equivalent of the above is:
2012-09-01 17:08:06 -04:00
```sql
2012-05-05 12:15:09 -04:00
SELECT * FROM clients LIMIT 1
2012-09-01 17:08:06 -04:00
```
2012-05-05 12:15:09 -04:00
2012-09-01 21:37:59 -04:00
`Model.take` returns `nil` if no record is found and no exception will be raised.
2012-05-05 14:24:16 -04:00
TIP: The retrieved record may vary depending on the database engine.
2012-05-05 12:15:09 -04:00
2012-09-01 21:37:59 -04:00
#### `first`
2009-02-03 20:44:58 -05:00
2012-09-01 19:34:21 -04:00
`Model.first` finds the first record ordered by the primary key. For example:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 11:05:26 -05:00
client = Client.first
2011-10-06 16:29:58 -04:00
# => #<Client id: 1, first_name: "Lifo">
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2012-05-05 12:15:09 -04:00
SELECT * FROM clients ORDER BY clients.id ASC LIMIT 1
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
`Model.first` returns `nil` if no matching record is found and no exception will be raised.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
#### `last`
2009-02-07 11:05:26 -05:00
2012-09-01 19:34:21 -04:00
`Model.last` finds the last record ordered by the primary key. For example:
2009-02-07 11:05:26 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 11:05:26 -05:00
client = Client.last
2011-10-06 16:29:58 -04:00
# => #<Client id: 221, first_name: "Russel">
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2009-02-07 11:05:26 -05:00
SELECT * FROM clients ORDER BY clients.id DESC LIMIT 1
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
`Model.last` returns `nil` if no matching record is found and no exception will be raised.
2009-02-07 11:05:26 -05:00
2012-09-01 21:37:59 -04:00
#### `find_by`
2012-03-30 07:44:45 -04:00
2012-09-01 19:34:21 -04:00
`Model.find_by` finds the first record matching some conditions. For example:
2012-03-30 07:44:45 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-03-30 07:44:45 -04:00
Client.find_by first_name: 'Lifo'
# => #<Client id: 1, first_name: "Lifo">
Client.find_by first_name: 'Jon'
# => nil
2012-09-01 17:08:06 -04:00
```
2012-03-30 07:44:45 -04:00
It is equivalent to writing:
2012-09-01 17:08:06 -04:00
```ruby
2012-05-05 12:15:09 -04:00
Client.where(first_name: 'Lifo').take
2012-09-01 17:08:06 -04:00
```
2012-03-30 07:44:45 -04:00
2012-09-01 21:37:59 -04:00
#### `take!`
2012-05-05 12:15:09 -04:00
2012-09-01 19:34:21 -04:00
`Model.take!` retrieves a record without any implicit ordering. For example:
2012-05-05 12:15:09 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-05 12:15:09 -04:00
client = Client.take!
# => #<Client id: 1, first_name: "Lifo">
2012-09-01 17:08:06 -04:00
```
2012-05-05 12:15:09 -04:00
The SQL equivalent of the above is:
2012-09-01 17:08:06 -04:00
```sql
2012-05-05 12:15:09 -04:00
SELECT * FROM clients LIMIT 1
2012-09-01 17:08:06 -04:00
```
2012-05-05 12:15:09 -04:00
2012-09-01 21:37:59 -04:00
`Model.take!` raises `ActiveRecord::RecordNotFound` if no matching record is found.
2012-05-05 12:15:09 -04:00
2012-09-01 21:37:59 -04:00
#### `first!`
2011-03-25 18:34:45 -04:00
2012-09-01 19:34:21 -04:00
`Model.first!` finds the first record ordered by the primary key. For example:
2011-03-25 18:34:45 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-03-25 18:34:45 -04:00
client = Client.first!
2011-10-06 16:29:58 -04:00
# => #<Client id: 1, first_name: "Lifo">
2012-09-01 17:08:06 -04:00
```
2011-03-25 18:34:45 -04:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2011-03-25 18:34:45 -04:00
2012-09-01 17:08:06 -04:00
```sql
2012-05-05 12:15:09 -04:00
SELECT * FROM clients ORDER BY clients.id ASC LIMIT 1
2012-09-01 17:08:06 -04:00
```
2011-03-25 18:34:45 -04:00
2012-09-01 21:37:59 -04:00
`Model.first!` raises `ActiveRecord::RecordNotFound` if no matching record is found.
2011-03-25 18:34:45 -04:00
2012-09-01 21:37:59 -04:00
#### `last!`
2011-03-25 18:34:45 -04:00
2012-09-01 19:34:21 -04:00
`Model.last!` finds the last record ordered by the primary key. For example:
2011-03-25 18:34:45 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-03-25 18:34:45 -04:00
client = Client.last!
2011-10-06 16:29:58 -04:00
# => #<Client id: 221, first_name: "Russel">
2012-09-01 17:08:06 -04:00
```
2011-03-25 18:34:45 -04:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2011-03-25 18:34:45 -04:00
2012-09-01 17:08:06 -04:00
```sql
2011-03-25 18:34:45 -04:00
SELECT * FROM clients ORDER BY clients.id DESC LIMIT 1
2012-09-01 17:08:06 -04:00
```
2011-03-25 18:34:45 -04:00
2012-09-01 21:37:59 -04:00
`Model.last!` raises `ActiveRecord::RecordNotFound` if no matching record is found.
2011-03-25 18:34:45 -04:00
2012-09-01 21:37:59 -04:00
#### `find_by!`
2012-03-30 07:44:45 -04:00
2012-09-01 21:37:59 -04:00
`Model.find_by!` finds the first record matching some conditions. It raises `ActiveRecord::RecordNotFound` if no matching record is found. For example:
2012-03-30 07:44:45 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-03-30 07:44:45 -04:00
Client.find_by! first_name: 'Lifo'
# => #<Client id: 1, first_name: "Lifo">
Client.find_by! first_name: 'Jon'
2012-05-05 14:24:16 -04:00
# => ActiveRecord::RecordNotFound
2012-09-01 17:08:06 -04:00
```
2012-03-30 07:44:45 -04:00
It is equivalent to writing:
2012-09-01 17:08:06 -04:00
```ruby
2012-05-05 12:15:09 -04:00
Client.where(first_name: 'Lifo').take!
2012-09-01 17:08:06 -04:00
```
2012-03-30 07:44:45 -04:00
2012-09-01 17:25:58 -04:00
### Retrieving Multiple Objects
2009-02-07 11:05:26 -05:00
2012-09-01 17:25:58 -04:00
#### Using Multiple Primary Keys
2009-02-07 11:05:26 -05:00
2012-09-01 19:34:21 -04:00
`Model.find(array_of_primary_key)` accepts an array of _primary keys_ , returning an array containing all of the matching records for the supplied _primary keys_ . For example:
2009-02-07 11:05:26 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 11:05:26 -05:00
# Find the clients with primary keys 1 and 10.
2011-10-05 17:52:50 -04:00
client = Client.find([1, 10]) # Or even Client.find(1, 10)
2011-10-06 16:29:58 -04:00
# => [#<Client id: 1, first_name: "Lifo">, #<Client id: 10, first_name: "Ryan">]
2012-09-01 17:08:06 -04:00
```
2009-02-07 11:05:26 -05:00
2011-10-05 17:52:50 -04:00
The SQL equivalent of the above is:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2009-02-07 11:05:26 -05:00
SELECT * FROM clients WHERE (clients.id IN (1,10))
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-03 21:21:24 -04:00
WARNING: `Model.find(array_of_primary_key)` will raise an `ActiveRecord::RecordNotFound` exception unless a matching record is found for **all** of the supplied primary keys.
2009-02-07 11:05:26 -05:00
2012-09-01 17:25:58 -04:00
#### take
2012-05-30 13:35:48 -04:00
2012-09-01 21:37:59 -04:00
`Model.take(limit)` retrieves the first number of records specified by `limit` without any explicit ordering:
2012-05-30 13:35:48 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-30 13:35:48 -04:00
Client.take(2)
2012-05-30 13:38:00 -04:00
# => [#<Client id: 1, first_name: "Lifo">,
2012-05-30 13:35:48 -04:00
#< Client id: 2 , first_name: " Raf " > ]
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
The SQL equivalent of the above is:
2012-09-01 17:08:06 -04:00
```sql
2012-05-30 13:35:48 -04:00
SELECT * FROM clients LIMIT 2
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
2012-09-01 17:25:58 -04:00
#### first
2012-05-30 13:35:48 -04:00
2012-09-01 21:37:59 -04:00
`Model.first(limit)` finds the first number of records specified by `limit` ordered by primary key:
2012-05-30 13:35:48 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-30 13:35:48 -04:00
Client.first(2)
2012-05-30 13:38:00 -04:00
# => [#<Client id: 1, first_name: "Lifo">,
2012-05-30 13:35:48 -04:00
#< Client id: 2 , first_name: " Raf " > ]
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
The SQL equivalent of the above is:
2012-09-01 17:08:06 -04:00
```sql
2013-02-18 11:41:09 -05:00
SELECT * FROM clients ORDER BY id ASC LIMIT 2
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
2012-09-01 17:25:58 -04:00
#### last
2012-05-30 13:35:48 -04:00
2012-09-01 21:37:59 -04:00
`Model.last(limit)` finds the number of records specified by `limit` ordered by primary key in descending order:
2012-05-30 13:35:48 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-30 13:35:48 -04:00
Client.last(2)
2012-05-30 13:38:00 -04:00
# => [#<Client id: 10, first_name: "Ryan">,
2012-05-30 13:35:48 -04:00
#< Client id: 9 , first_name: " John " > ]
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
The SQL equivalent of the above is:
2012-09-01 17:08:06 -04:00
```sql
2013-02-18 11:41:09 -05:00
SELECT * FROM clients ORDER BY id DESC LIMIT 2
2012-09-01 17:08:06 -04:00
```
2012-05-30 13:35:48 -04:00
2012-09-01 17:25:58 -04:00
### Retrieving Multiple Objects in Batches
2009-03-14 10:30:49 -04:00
2011-10-11 09:27:01 -04:00
We often need to iterate over a large set of records, as when we send a newsletter to a large set of users, or when we export data.
2009-03-14 10:30:49 -04:00
2011-10-11 09:27:01 -04:00
This may appear straightforward:
2009-03-14 10:30:49 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-10-11 09:27:01 -04:00
# This is very inefficient when the users table has thousands of rows.
2010-08-30 18:05:14 -04:00
User.all.each do |user|
2009-03-14 10:30:49 -04:00
NewsLetter.weekly_deliver(user)
end
2012-09-01 17:08:06 -04:00
```
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
But this approach becomes increasingly impractical as the table size increases, since `User.all.each` instructs Active Record to fetch _the entire table_ in a single pass, build a model object per row, and then keep the entire array of model objects in memory. Indeed, if we have a large number of records, the entire collection may exceed the amount of memory available.
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
Rails provides two methods that address this problem by dividing records into memory-friendly batches for processing. The first method, `find_each` , retrieves a batch of records and then yields _each_ record to the block individually as a model. The second method, `find_in_batches` , retrieves a batch of records and then yields _the entire batch_ to the block as an array of models.
2011-10-11 09:27:01 -04:00
2012-09-01 21:37:59 -04:00
TIP: The `find_each` and `find_in_batches` methods are intended for use in the batch processing of a large number of records that wouldn't fit in memory all at once. If you just need to loop over a thousand records the regular find methods are the preferred option.
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
#### `find_each`
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
The `find_each` method retrieves a batch of records and then yields _each_ record to the block individually as a model. In the following example, `find_each` will retrieve 1000 records (the current default for both `find_each` and `find_in_batches` ) and then yield each record individually to the block as a model. This process is repeated until all of the records have been processed:
2009-03-14 10:30:49 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2009-03-14 10:30:49 -04:00
User.find_each do |user|
NewsLetter.weekly_deliver(user)
end
2012-09-01 17:08:06 -04:00
```
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
##### Options for `find_each`
2011-10-11 09:27:01 -04:00
2012-09-01 21:37:59 -04:00
The `find_each` method accepts most of the options allowed by the regular `find` method, except for `:order` and `:limit` , which are reserved for internal use by `find_each` .
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
Two additional options, `:batch_size` and `:start` , are available as well.
2009-03-14 10:30:49 -04:00
2012-09-06 22:26:59 -04:00
**`:batch_size`**
2011-10-11 09:27:01 -04:00
2012-09-01 21:37:59 -04:00
The `:batch_size` option allows you to specify the number of records to be retrieved in each batch, before being passed individually to the block. For example, to retrieve records in batches of 5000:
2009-03-14 10:30:49 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
User.find_each(batch_size: 5000) do |user|
2009-03-14 10:30:49 -04:00
NewsLetter.weekly_deliver(user)
end
2012-09-01 17:08:06 -04:00
```
2009-03-14 10:30:49 -04:00
2012-09-06 22:26:59 -04:00
**`:start`**
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
By default, records are fetched in ascending order of the primary key, which must be an integer. The `:start` option allows you to configure the first ID of the sequence whenever the lowest ID is not the one you need. This would be useful, for example, if you wanted to resume an interrupted batch process, provided you saved the last processed ID as a checkpoint.
2009-03-14 10:30:49 -04:00
2011-10-11 09:27:01 -04:00
For example, to send newsletters only to users with the primary key starting from 2000, and to retrieve them in batches of 5000:
2009-03-14 10:30:49 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
User.find_each(start: 2000, batch_size: 5000) do |user|
2009-03-14 10:30:49 -04:00
NewsLetter.weekly_deliver(user)
end
2012-09-01 17:08:06 -04:00
```
2009-03-14 10:30:49 -04:00
2012-09-01 19:34:21 -04:00
Another example would be if you wanted multiple workers handling the same processing queue. You could have each worker handle 10000 records by setting the appropriate `:start` option on each worker.
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
#### `find_in_batches`
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
The `find_in_batches` method is similar to `find_each` , since both retrieve batches of records. The difference is that `find_in_batches` yields _batches_ to the block as an array of models, instead of individually. The following example will yield to the supplied block an array of up to 1000 invoices at a time, with the final block containing any remaining invoices:
2009-03-14 10:30:49 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-10-11 09:27:01 -04:00
# Give add_invoices an array of 1000 invoices at a time
2012-11-15 15:28:24 -05:00
Invoice.find_in_batches(include: :invoice_lines) do |invoices|
2009-03-14 10:30:49 -04:00
export.add_invoices(invoices)
end
2012-09-01 17:08:06 -04:00
```
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
NOTE: The `:include` option allows you to name associations that should be loaded alongside with the models.
2009-03-14 10:30:49 -04:00
2012-09-01 21:37:59 -04:00
##### Options for `find_in_batches`
2011-10-11 09:27:01 -04:00
2012-09-01 21:37:59 -04:00
The `find_in_batches` method accepts the same `:batch_size` and `:start` options as `find_each` , as well as most of the options allowed by the regular `find` method, except for `:order` and `:limit` , which are reserved for internal use by `find_in_batches` .
2011-10-11 09:27:01 -04:00
2012-09-01 17:25:58 -04:00
Conditions
----------
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
The `where` method allows you to specify conditions to limit the records returned, representing the `WHERE` -part of the SQL statement. Conditions can either be specified as a string, array, or hash.
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Pure String Conditions
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you'd like to add conditions to your find, you could just specify them in there, just like `Client.where("orders_count = '2'")` . This will find all clients where the `orders_count` field's value is 2.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
WARNING: Building your own conditions as pure strings can leave you vulnerable to SQL injection exploits. For example, `Client.where("first_name LIKE '%#{params[:first_name]}%'")` is not safe. See the next section for the preferred way to handle conditions using an array.
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Array Conditions
2009-02-03 20:44:58 -05:00
2011-10-11 09:27:01 -04:00
Now what if that number could vary, say as an argument from somewhere? The find would then take the form:
2009-02-07 11:41:29 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:12:58 -04:00
Client.where("orders_count = ?", params[:orders])
2012-09-01 17:08:06 -04:00
```
2009-02-07 11:41:29 -05:00
2012-09-01 21:37:59 -04:00
Active Record will go through the first element in the conditions value and any additional elements will replace the question marks `(?)` in the first element.
2009-02-07 11:41:29 -05:00
2011-10-11 09:27:01 -04:00
If you want to specify multiple conditions:
2009-02-07 11:41:29 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:12:58 -04:00
Client.where("orders_count = ? AND locked = ?", params[:orders], false)
2012-09-01 17:08:06 -04:00
```
2009-02-07 11:41:29 -05:00
2012-09-01 21:37:59 -04:00
In this example, the first question mark will be replaced with the value in `params[:orders]` and the second will be replaced with the SQL representation of `false` , which depends on the adapter.
2009-02-03 20:44:58 -05:00
2011-10-11 09:27:01 -04:00
This code is highly preferable:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:12:58 -04:00
Client.where("orders_count = ?", params[:orders])
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-10-11 09:27:01 -04:00
to this code:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-03 18:27:27 -05:00
Client.where("orders_count = #{params[:orders]}")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2013-12-02 00:36:29 -05:00
because of argument safety. Putting the variable directly into the conditions string will pass the variable to the database **as-is** . This means that it will be an unescaped variable directly from a user who may have malicious intent. If you do this, you put your entire database at risk because once a user finds out they can exploit your database they can do just about anything to it. Never ever put your arguments directly inside the conditions string.
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
TIP: For more information on the dangers of SQL injection, see the [Ruby on Rails Security Guide ](security.html#sql-injection ).
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
#### Placeholder Conditions
2009-02-07 11:41:29 -05:00
2012-09-01 21:37:59 -04:00
Similar to the `(?)` replacement style of params, you can also specify keys/values hash in your array conditions:
2009-02-07 11:41:29 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:19:43 -04:00
Client.where("created_at >= :start_date AND created_at < = :end_date",
2012-11-15 15:28:24 -05:00
{start_date: params[:start_date], end_date: params[:end_date]})
2012-09-01 17:08:06 -04:00
```
2009-02-07 11:41:29 -05:00
This makes for clearer readability if you have a large number of variable conditions.
2012-09-01 17:25:58 -04:00
### Hash Conditions
2009-02-03 20:44:58 -05:00
2010-07-14 04:39:00 -04:00
Active Record also allows you to pass in hash conditions which can increase the readability of your conditions syntax. With hash conditions, you pass in a hash with keys of the fields you want conditionalised and the values of how you want to conditionalise them:
2009-02-03 20:44:58 -05:00
2009-02-07 11:41:29 -05:00
NOTE: Only equality, range and subset checking are possible with Hash conditions.
2012-09-01 17:25:58 -04:00
#### Equality Conditions
2009-02-07 11:41:29 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(locked: true)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2010-07-14 05:30:12 -04:00
The field name can also be a string:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:19:43 -04:00
Client.where('locked' => true)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-11-29 07:35:13 -05:00
In the case of a belongs_to relationship, an association key can be used to specify the model if an Active Record object is used as the value. This method works with polymorphic relationships as well.
2012-09-11 14:11:51 -04:00
2012-09-01 21:37:59 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Post.where(author: author)
2013-11-19 07:54:46 -05:00
Author.joins(:posts).where(posts: { author: author })
2012-09-01 21:37:59 -04:00
```
2012-09-11 14:11:51 -04:00
2012-11-15 15:28:24 -05:00
NOTE: The values cannot be symbols. For example, you cannot do `Client.where(status: :active)` .
2012-04-22 23:14:52 -04:00
2012-09-01 17:25:58 -04:00
#### Range Conditions
2009-02-07 11:41:29 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(created_at: (Time.now.midnight - 1.day)..Time.now.midnight)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
This will find all clients created yesterday by using a `BETWEEN` SQL statement:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2009-02-03 20:44:58 -05:00
SELECT * FROM clients WHERE (clients.created_at BETWEEN '2008-12-21 00:00:00' AND '2008-12-22 00:00:00')
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
This demonstrates a shorter syntax for the examples in [Array Conditions ](#array-conditions )
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
#### Subset Conditions
2009-02-07 11:41:29 -05:00
2012-09-01 21:37:59 -04:00
If you want to find records using the `IN` expression you can pass an array to the conditions hash:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(orders_count: [1,3,5])
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 11:41:29 -05:00
This code will generate SQL like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2009-02-16 02:47:43 -05:00
SELECT * FROM clients WHERE (clients.orders_count IN (1,3,5))
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2013-03-19 18:05:44 -04:00
### NOT Conditions
2012-11-04 23:56:30 -05:00
2013-03-19 18:05:44 -04:00
`NOT` SQL queries can be built by `where.not` .
2012-11-04 23:56:30 -05:00
```ruby
Post.where.not(author: author)
```
2013-08-17 12:08:53 -04:00
In other words, this query can be generated by calling `where` with no argument, then immediately chain with `not` passing `where` conditions.
2012-11-04 23:56:30 -05:00
2012-09-01 17:25:58 -04:00
Ordering
--------
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
To retrieve records from the database in a specific order, you can use the `order` method.
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
For example, if you're getting a set of records and want to order them in ascending order by the `created_at` field in your table:
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-08-19 22:12:16 -04:00
Client.order(:created_at)
# OR
2010-02-03 18:27:27 -05:00
Client.order("created_at")
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
You could specify `ASC` or `DESC` as well:
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-08-19 22:12:16 -04:00
Client.order(created_at: :desc)
# OR
Client.order(created_at: :asc)
# OR
2010-02-03 18:27:27 -05:00
Client.order("created_at DESC")
2009-02-07 13:10:42 -05:00
# OR
2010-02-03 18:27:27 -05:00
Client.order("created_at ASC")
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
Or ordering by multiple fields:
2012-09-01 17:08:06 -04:00
```ruby
2013-08-19 22:12:16 -04:00
Client.order(orders_count: :asc, created_at: :desc)
# OR
Client.order(:orders_count, created_at: :desc)
# OR
2010-02-03 18:27:27 -05:00
Client.order("orders_count ASC, created_at DESC")
2012-01-31 09:09:08 -05:00
# OR
Client.order("orders_count ASC", "created_at DESC")
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
2013-07-29 22:18:33 -04:00
If you want to call `order` multiple times e.g. in different context, new order will append previous one
2012-07-31 03:24:18 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-07-31 03:24:18 -04:00
Client.order("orders_count ASC").order("created_at DESC")
2013-07-29 22:18:33 -04:00
# SELECT * FROM clients ORDER BY orders_count ASC, created_at DESC
2012-09-01 17:08:06 -04:00
```
2012-07-31 03:24:18 -04:00
2012-09-01 17:25:58 -04:00
Selecting Specific Fields
-------------------------
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
By default, `Model.find` selects all the fields from the result set using `select *` .
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
To select only a subset of fields from the result set, you can specify the subset via the `select` method.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
For example, to select only `viewable_by` and `locked` columns:
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-03 18:27:27 -05:00
Client.select("viewable_by, locked")
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
The SQL query used by this find call will be somewhat like:
2012-09-01 17:08:06 -04:00
```sql
2009-02-07 13:10:42 -05:00
SELECT viewable_by, locked FROM clients
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
Be careful because this also means you're initializing a model object with only the fields that you've selected. If you attempt to access a field that is not in the initialized record you'll receive:
2012-09-01 20:45:26 -04:00
```bash
2011-04-20 10:43:35 -04:00
ActiveModel::MissingAttributeError: missing attribute: < attribute >
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-03 21:21:24 -04:00
Where `<attribute>` is the attribute you asked for. The `id` method will not raise the `ActiveRecord::MissingAttributeError` , so just be careful when working with associations because they need the `id` method to function properly.
2009-02-07 13:10:42 -05:00
2013-03-12 05:23:08 -04:00
If you would like to only grab a single record per unique value in a certain field, you can use `distinct` :
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-03-12 05:23:08 -04:00
Client.select(:name).distinct
2012-09-01 17:08:06 -04:00
```
2011-11-04 12:10:18 -04:00
This would generate SQL like:
2012-09-01 17:08:06 -04:00
```sql
2011-11-04 12:10:18 -04:00
SELECT DISTINCT name FROM clients
2012-09-01 17:08:06 -04:00
```
2011-11-04 12:10:18 -04:00
You can also remove the uniqueness constraint:
2012-09-01 17:08:06 -04:00
```ruby
2013-03-12 05:23:08 -04:00
query = Client.select(:name).distinct
2011-11-04 12:10:18 -04:00
# => Returns unique names
2013-03-12 05:23:08 -04:00
query.distinct(false)
2011-11-04 12:10:18 -04:00
# => Returns all names, even if there are duplicates
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Limit and Offset
----------------
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
To apply `LIMIT` to the SQL fired by the `Model.find` , you can specify the `LIMIT` using `limit` and `offset` methods on the relation.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
You can use `limit` to specify the number of records to be retrieved, and use `offset` to specify the number of records to skip before starting to return the records. For example
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-03 18:27:27 -05:00
Client.limit(5)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2010-07-14 07:17:01 -04:00
will return a maximum of 5 clients and because it specifies no offset it will return the first 5 in the table. The SQL it executes looks like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2009-02-03 20:44:58 -05:00
SELECT * FROM clients LIMIT 5
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
Adding `offset` to that
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-07-14 07:17:01 -04:00
Client.limit(5).offset(30)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2010-07-14 07:17:01 -04:00
will return instead a maximum of 5 clients beginning with the 31st. The SQL looks like:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2011-03-05 13:29:23 -05:00
SELECT * FROM clients LIMIT 5 OFFSET 30
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Group
-----
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
To apply a `GROUP BY` clause to the SQL fired by the finder, you can specify the `group` method on the find.
2009-02-07 13:10:42 -05:00
For example, if you want to find a collection of the dates orders were created on:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-06-28 19:04:11 -04:00
Order.select("date(created_at) as ordered_date, sum(price) as total_price").group("date(created_at)")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
And this will give you a single `Order` object for each date where there are orders in the database.
2009-02-03 20:44:58 -05:00
The SQL that would be executed would be something like this:
2012-09-01 17:08:06 -04:00
```sql
2012-06-22 08:30:00 -04:00
SELECT date(created_at) as ordered_date, sum(price) as total_price
FROM orders
2012-04-13 15:08:03 -04:00
GROUP BY date(created_at)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Having
------
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
SQL uses the `HAVING` clause to specify conditions on the `GROUP BY` fields. You can add the `HAVING` clause to the SQL fired by the `Model.find` by adding the `:having` option to the find.
2009-02-03 20:44:58 -05:00
2009-02-07 13:10:42 -05:00
For example:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-09-03 21:21:24 -04:00
Order.select("date(created_at) as ordered_date, sum(price) as total_price").
group("date(created_at)").having("sum(price) > ?", 100)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 13:10:42 -05:00
The SQL that would be executed would be something like this:
2012-09-01 17:08:06 -04:00
```sql
2012-06-22 08:30:00 -04:00
SELECT date(created_at) as ordered_date, sum(price) as total_price
FROM orders
GROUP BY date(created_at)
2012-04-13 15:08:03 -04:00
HAVING sum(price) > 100
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
2011-06-28 19:29:34 -04:00
This will return single order objects for each day, but only those that are ordered more than $100 in a day.
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Overriding Conditions
---------------------
2011-01-15 13:09:32 -05:00
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
### `unscope`
2011-01-15 13:09:32 -05:00
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
You can specify certain conditions to be removed using the `unscope` method. For example:
2011-01-15 13:09:32 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-01-15 13:09:32 -05:00
Post.where('id > 10').limit(20).order('id asc').except(:order)
2012-09-01 17:08:06 -04:00
```
2011-01-15 13:09:32 -05:00
The SQL that would be executed:
2012-09-01 17:08:06 -04:00
```sql
2011-01-15 13:09:32 -05:00
SELECT * FROM posts WHERE id > 10 LIMIT 20
2013-06-13 14:00:14 -04:00
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
# Original query without `unscope`
2013-06-13 14:00:14 -04:00
SELECT * FROM posts WHERE id > 10 ORDER BY id asc LIMIT 20
2012-09-01 17:08:06 -04:00
```
2011-01-15 13:09:32 -05:00
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
You can additionally unscope specific where clauses. For example:
2013-02-11 23:23:01 -05:00
```ruby
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
Post.where(id: 10, trashed: false).unscope(where: :id)
# => SELECT "posts".* FROM "posts" WHERE trashed = 0
2013-02-11 23:23:01 -05:00
```
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
A relation which has used `unscope` will affect any relation it is
merged in to:
2013-02-11 23:23:01 -05:00
```ruby
Fix ActiveRecord::Relation#unscope
I'm pretty confused about the addition of this method. The documentation
says that it was intended to allow the removal of values from the
default scope (in contrast to #except). However it behaves exactly the
same as except: https://gist.github.com/jonleighton/7537008 (other than
having a slightly enhanced syntax).
The removal of the default scope is allowed by
94924dc32baf78f13e289172534c2e71c9c8cade, which was not a change we
could make until 4.1 due to the need to deprecate things. However after
that change #unscope still gives us nothing that #except doesn't already
give us.
However there *is* a desire to be able to unscope stuff in a way that
persists across merges, which would allow associations to be defined
which unscope stuff from the default scope of the associated model. E.g.
has_many :comments, -> { unscope where: :trashed }
So that's what this change implements. I've also corrected the
documentation. I removed the guide references to #except as I think
unscope really supercedes #except now.
While we're here, there's also a potential desire to be able to write
this:
has_many :comments, -> { unscoped }
However, it doesn't make sense and would not be straightforward to
implement. While with #unscope we're specifying exactly what we want to
be removed from the relation, with "unscoped" we're just saying that we
want it to not have some things which were added earlier on by the
default scope. However in the case of an association, we surely don't
want *all* conditions to be removed, otherwise the above would just
become "SELECT * FROM comments" with no foreign key constraint.
To make the above work, we'd have to somehow tag the relation values
which get added when evaluating the default scope in order to
differentiate them from other relation values. Which is way too much
complexity and therefore not worth it when most use cases can be
satisfied with unscope.
Closes #10643, #11061.
2013-11-20 16:51:35 -05:00
Post.order('id asc').merge(Post.unscope(:order))
# => SELECT "posts".* FROM "posts"
2013-02-11 23:23:01 -05:00
```
2012-09-01 21:37:59 -04:00
### `only`
2011-01-15 13:09:32 -05:00
2012-09-01 21:37:59 -04:00
You can also override conditions using the `only` method. For example:
2011-01-15 13:09:32 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-01-15 13:09:32 -05:00
Post.where('id > 10').limit(20).order('id desc').only(:order, :where)
2012-09-01 17:08:06 -04:00
```
2011-01-15 13:09:32 -05:00
The SQL that would be executed:
2012-09-01 17:08:06 -04:00
```sql
2011-01-15 13:09:32 -05:00
SELECT * FROM posts WHERE id > 10 ORDER BY id DESC
2013-06-13 14:00:14 -04:00
# Original query without `only`
SELECT "posts".* FROM "posts" WHERE (id > 10) ORDER BY id desc LIMIT 20
2012-09-01 17:08:06 -04:00
```
2011-01-15 13:09:32 -05:00
2012-09-01 21:37:59 -04:00
### `reorder`
2011-04-27 16:20:00 -04:00
2012-09-01 21:37:59 -04:00
The `reorder` method overrides the default scope order. For example:
2011-04-27 16:20:00 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-04-27 16:20:00 -04:00
class Post < ActiveRecord::Base
..
..
2013-05-01 14:41:54 -04:00
has_many :comments, -> { order('posted_at DESC') }
2011-04-27 16:20:00 -04:00
end
Post.find(10).comments.reorder('name')
2012-09-01 17:08:06 -04:00
```
2011-04-27 16:20:00 -04:00
The SQL that would be executed:
2012-09-01 17:08:06 -04:00
```sql
2011-04-27 16:20:00 -04:00
SELECT * FROM posts WHERE id = 10 ORDER BY name
2012-09-01 17:08:06 -04:00
```
2011-04-27 16:20:00 -04:00
2012-09-01 21:37:59 -04:00
In case the `reorder` clause is not used, the SQL executed would be:
2011-04-27 16:20:00 -04:00
2012-09-01 17:08:06 -04:00
```sql
2011-04-27 16:20:00 -04:00
SELECT * FROM posts WHERE id = 10 ORDER BY posted_at DESC
2012-09-01 17:08:06 -04:00
```
2011-04-27 16:20:00 -04:00
2012-09-01 21:37:59 -04:00
### `reverse_order`
2011-06-19 16:42:21 -04:00
2012-09-01 21:37:59 -04:00
The `reverse_order` method reverses the ordering clause if specified.
2011-06-19 16:42:21 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-06-19 16:42:21 -04:00
Client.where("orders_count > 10").order(:name).reverse_order
2012-09-01 17:08:06 -04:00
```
2011-06-19 16:42:21 -04:00
The SQL that would be executed:
2011-08-17 17:37:27 -04:00
2012-09-01 17:08:06 -04:00
```sql
2011-06-19 16:42:21 -04:00
SELECT * FROM clients WHERE orders_count > 10 ORDER BY name DESC
2012-09-01 17:08:06 -04:00
```
2011-06-19 16:42:21 -04:00
2012-09-01 21:37:59 -04:00
If no ordering clause is specified in the query, the `reverse_order` orders by the primary key in reverse order.
2011-06-19 16:42:21 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-06-19 16:42:21 -04:00
Client.where("orders_count > 10").reverse_order
2012-09-01 17:08:06 -04:00
```
2011-06-19 16:42:21 -04:00
The SQL that would be executed:
2011-08-17 17:37:27 -04:00
2012-09-01 17:08:06 -04:00
```sql
2011-06-19 16:42:21 -04:00
SELECT * FROM clients WHERE orders_count > 10 ORDER BY clients.id DESC
2012-09-01 17:08:06 -04:00
```
2011-06-19 16:42:21 -04:00
2012-09-06 22:26:59 -04:00
This method accepts **no** arguments.
2011-06-19 16:42:21 -04:00
2013-11-25 01:30:46 -05:00
### `rewhere`
The `rewhere` method overrides an existing, named where condition. For example:
```ruby
Post.where(trashed: true).rewhere(trashed: false)
```
The SQL that would be executed:
```sql
SELECT * FROM posts WHERE `trashed` = 0
```
In case the `rewhere` clause is not used,
```ruby
Post.where(trashed: true).where(trashed: false)
```
the SQL executed would be:
```sql
SELECT * FROM posts WHERE `trashed` = 1 AND `trashed` = 0
```
2012-09-01 17:25:58 -04:00
Null Relation
-------------
2012-02-01 12:49:38 -05:00
2012-09-01 21:37:59 -04:00
The `none` method returns a chainable relation with no records. Any subsequent conditions chained to the returned relation will continue generating empty relations. This is useful in scenarios where you need a chainable response to a method or a scope that could return zero results.
2012-02-01 12:49:38 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-02-01 12:49:38 -05:00
Post.none # returns an empty Relation and fires no queries.
2012-09-01 17:08:06 -04:00
```
2012-02-01 12:49:38 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-02-01 12:49:38 -05:00
# The visible_posts method below is expected to return a Relation.
2012-11-15 15:28:24 -05:00
@posts = current_user.visible_posts.where(name: params[:name])
2012-02-01 12:49:38 -05:00
def visible_posts
case role
when 'Country Manager'
2012-11-15 15:28:24 -05:00
Post.where(country: country)
2012-02-01 12:49:38 -05:00
when 'Reviewer'
Post.published
when 'Bad User'
Post.none # => returning [] or nil breaks the caller code in this case
end
end
2012-09-01 17:08:06 -04:00
```
2012-02-01 12:49:38 -05:00
2012-09-01 17:25:58 -04:00
Readonly Objects
----------------
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
Active Record provides `readonly` method on a relation to explicitly disallow modification of any of the returned objects. Any attempt to alter a readonly record will not succeed, raising an `ActiveRecord::ReadOnlyRecord` exception.
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 19:14:49 -04:00
client = Client.readonly.first
client.visits += 1
2009-02-03 20:44:58 -05:00
client.save
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
As `client` is explicitly set to be a readonly object, the above code will raise an `ActiveRecord::ReadOnlyRecord` exception when calling `client.save` with an updated value of _visits_ .
2010-08-30 19:14:49 -04:00
2012-09-01 17:25:58 -04:00
Locking Records for Update
--------------------------
2009-02-07 13:10:42 -05:00
2010-07-14 04:39:00 -04:00
Locking is helpful for preventing race conditions when updating records in the database and ensuring atomic updates.
Active Record provides two locking mechanisms:
2009-02-07 13:10:42 -05:00
* Optimistic Locking
* Pessimistic Locking
2012-09-01 17:25:58 -04:00
### Optimistic Locking
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
Optimistic locking allows multiple users to access the same record for edits, and assumes a minimum of conflicts with the data. It does this by checking whether another process has made changes to a record since it was opened. An `ActiveRecord::StaleObjectError` exception is thrown if that has occurred and the update is ignored.
2009-02-07 13:10:42 -05:00
2012-09-03 21:21:24 -04:00
**Optimistic locking column**
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
In order to use optimistic locking, the table needs to have a column called `lock_version` of type integer. Each time the record is updated, Active Record increments the `lock_version` column. If an update request is made with a lower value in the `lock_version` field than is currently in the `lock_version` column in the database, the update request will fail with an `ActiveRecord::StaleObjectError` . Example:
2009-02-07 13:10:42 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 13:10:42 -05:00
c1 = Client.find(1)
c2 = Client.find(1)
2010-06-13 22:35:16 -04:00
c1.first_name = "Michael"
2009-02-07 13:10:42 -05:00
c1.save
c2.name = "should fail"
2011-09-27 21:11:01 -04:00
c2.save # Raises an ActiveRecord::StaleObjectError
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
You're then responsible for dealing with the conflict by rescuing the exception and either rolling back, merging, or otherwise apply the business logic needed to resolve the conflict.
2012-09-01 19:34:21 -04:00
This behavior can be turned off by setting `ActiveRecord::Base.lock_optimistically = false` .
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
To override the name of the `lock_version` column, `ActiveRecord::Base` provides a class attribute called `locking_column` :
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 13:10:42 -05:00
class Client < ActiveRecord::Base
2012-01-31 09:09:08 -05:00
self.locking_column = :lock_client_column
2009-02-03 20:44:58 -05:00
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Pessimistic Locking
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
Pessimistic locking uses a locking mechanism provided by the underlying database. Using `lock` when building a relation obtains an exclusive lock on the selected rows. Relations using `lock` are usually wrapped inside a transaction for preventing deadlock conditions.
2009-02-07 13:10:42 -05:00
For example:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 13:10:42 -05:00
Item.transaction do
2010-08-30 18:52:27 -04:00
i = Item.lock.first
2009-02-07 13:10:42 -05:00
i.name = 'Jones'
i.save
2009-02-03 20:44:58 -05:00
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 13:10:42 -05:00
The above session produces the following SQL for a MySQL backend:
2012-09-01 17:08:06 -04:00
```sql
2009-02-07 13:10:42 -05:00
SQL (0.2ms) BEGIN
Item Load (0.3ms) SELECT * FROM `items` LIMIT 1 FOR UPDATE
Item Update (0.4ms) UPDATE `items` SET `updated_at` = '2009-02-07 18:05:56', `name` = 'Jones' WHERE `id` = 1
SQL (0.8ms) COMMIT
2012-09-01 17:08:06 -04:00
```
2009-02-07 13:10:42 -05:00
2012-09-01 21:37:59 -04:00
You can also pass raw SQL to the `lock` method for allowing different types of locks. For example, MySQL has an expression called `LOCK IN SHARE MODE` where you can lock a record but still allow other queries to read it. To specify this expression just pass it in as the lock option:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 13:10:42 -05:00
Item.transaction do
2010-08-30 18:52:27 -04:00
i = Item.lock("LOCK IN SHARE MODE").find(1)
2009-02-07 13:10:42 -05:00
i.increment!(:views)
end
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-01-18 17:03:55 -05:00
If you already have an instance of your model, you can start a transaction and acquire the lock in one go using the following code:
2012-09-01 17:08:06 -04:00
```ruby
2012-01-18 17:03:55 -05:00
item = Item.first
item.with_lock do
# This block is called within a transaction,
# item is already locked.
item.increment!(:views)
end
2012-09-01 17:08:06 -04:00
```
2012-01-18 17:03:55 -05:00
2012-09-01 17:25:58 -04:00
Joining Tables
--------------
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Active Record provides a finder method called `joins` for specifying `JOIN` clauses on the resulting SQL. There are multiple ways to use the `joins` method.
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
### Using a String SQL Fragment
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
You can just supply the raw SQL specifying the `JOIN` clause to `joins` :
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 19:01:41 -04:00
Client.joins('LEFT OUTER JOIN addresses ON addresses.client_id = clients.id')
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
This will result in the following SQL:
2012-09-01 17:08:06 -04:00
```sql
2009-03-15 10:13:03 -04:00
SELECT clients.* FROM clients LEFT OUTER JOIN addresses ON addresses.client_id = clients.id
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
### Using Array/Hash of Named Associations
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
WARNING: This method only works with `INNER JOIN` .
2009-02-07 16:50:06 -05:00
2012-09-02 01:08:20 -04:00
Active Record lets you use the names of the [associations ](association_basics.html ) defined on the model as a shortcut for specifying `JOIN` clause for those associations when using the `joins` method.
2009-02-07 16:50:06 -05:00
2013-09-04 10:50:10 -04:00
For example, consider the following `Category` , `Post` , `Comment` , `Guest` and `Tag` models:
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 16:50:06 -05:00
class Category < ActiveRecord::Base
has_many :posts
end
class Post < ActiveRecord::Base
belongs_to :category
has_many :comments
has_many :tags
end
2011-05-26 22:19:10 -04:00
class Comment < ActiveRecord::Base
2009-02-07 16:50:06 -05:00
belongs_to :post
has_one :guest
end
class Guest < ActiveRecord::Base
belongs_to :comment
end
2011-05-26 22:19:10 -04:00
class Tag < ActiveRecord::Base
belongs_to :post
end
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Now all of the following will produce the expected join queries using `INNER JOIN` :
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
#### Joining a Single Association
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-03 18:27:27 -05:00
Category.joins(:posts)
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
This produces:
2012-09-01 17:08:06 -04:00
```sql
2009-02-07 16:50:06 -05:00
SELECT categories.* FROM categories
INNER JOIN posts ON posts.category_id = categories.id
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2013-03-11 11:10:43 -04:00
Or, in English: "return a Category object for all categories with posts". Note that you will see duplicate categories if more than one post has the same category. If you want unique categories, you can use `Category.joins(:posts).uniq` .
2011-05-26 22:19:10 -04:00
2012-09-01 17:25:58 -04:00
#### Joining Multiple Associations
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-03 18:27:27 -05:00
Post.joins(:category, :comments)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 16:50:06 -05:00
This produces:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2010-08-14 01:13:00 -04:00
SELECT posts.* FROM posts
2009-02-07 16:50:06 -05:00
INNER JOIN categories ON posts.category_id = categories.id
INNER JOIN comments ON comments.post_id = posts.id
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-05-26 22:19:10 -04:00
Or, in English: "return all posts that have a category and at least one comment". Note again that posts with multiple comments will show up multiple times.
2012-09-01 17:25:58 -04:00
#### Joining Nested Associations (Single Level)
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Post.joins(comments: :guest)
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2011-05-26 22:19:10 -04:00
This produces:
2012-09-01 17:08:06 -04:00
```sql
2011-05-26 22:19:10 -04:00
SELECT posts.* FROM posts
INNER JOIN comments ON comments.post_id = posts.id
INNER JOIN guests ON guests.comment_id = comments.id
2012-09-01 17:08:06 -04:00
```
2011-05-26 22:19:10 -04:00
Or, in English: "return all posts that have a comment made by a guest."
2012-09-01 17:25:58 -04:00
#### Joining Nested Associations (Multiple Level)
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-11-19 07:54:46 -05:00
Category.joins(posts: [{ comments: :guest }, :tags])
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2011-05-26 22:19:10 -04:00
This produces:
2012-09-01 17:08:06 -04:00
```sql
2011-05-26 22:19:10 -04:00
SELECT categories.* FROM categories
INNER JOIN posts ON posts.category_id = categories.id
INNER JOIN comments ON comments.post_id = posts.id
INNER JOIN guests ON guests.comment_id = comments.id
INNER JOIN tags ON tags.post_id = posts.id
2012-09-01 17:08:06 -04:00
```
2011-05-26 22:19:10 -04:00
2012-09-01 17:25:58 -04:00
### Specifying Conditions on the Joined Tables
2009-02-07 16:50:06 -05:00
2012-11-18 03:34:59 -05:00
You can specify conditions on the joined tables using the regular [Array ](#array-conditions ) and [String ](#pure-string-conditions ) conditions. [Hash conditions ](#hash-conditions ) provides a special syntax for specifying conditions for the joined tables:
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 16:50:06 -05:00
time_range = (Time.now.midnight - 1.day)..Time.now.midnight
2010-02-03 18:27:27 -05:00
Client.joins(:orders).where('orders.created_at' => time_range)
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2010-07-14 05:30:12 -04:00
An alternative and cleaner syntax is to nest the hash conditions:
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-07 16:50:06 -05:00
time_range = (Time.now.midnight - 1.day)..Time.now.midnight
2013-11-19 07:54:46 -05:00
Client.joins(:orders).where(orders: { created_at: time_range })
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
This will find all clients who have orders that were created yesterday, again using a `BETWEEN` SQL expression.
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
Eager Loading Associations
--------------------------
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Eager loading is the mechanism for loading the associated records of the objects returned by `Model.find` using as few queries as possible.
2009-02-03 20:44:58 -05:00
2012-09-03 21:21:24 -04:00
**N + 1 queries problem**
2009-02-07 16:50:06 -05:00
Consider the following code, which finds 10 clients and prints their postcodes:
2012-09-01 17:08:06 -04:00
```ruby
2011-01-08 15:54:30 -05:00
clients = Client.limit(10)
2009-02-07 16:50:06 -05:00
clients.each do |client|
puts client.address.postcode
end
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2012-09-03 21:21:24 -04:00
This code looks fine at the first sight. But the problem lies within the total number of queries executed. The above code executes 1 (to find 10 clients) + 10 (one per each client to load the address) = **11** queries in total.
2009-02-07 16:50:06 -05:00
2012-09-03 21:21:24 -04:00
**Solution to N + 1 queries problem**
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Active Record lets you specify in advance all the associations that are going to be loaded. This is possible by specifying the `includes` method of the `Model.find` call. With `includes` , Active Record ensures that all of the specified associations are loaded using the minimum possible number of queries.
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Revisiting the above case, we could rewrite `Client.limit(10)` to use eager load addresses:
2009-02-07 16:50:06 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-04 14:11:59 -05:00
clients = Client.includes(:address).limit(10)
2009-02-07 16:50:06 -05:00
clients.each do |client|
puts client.address.postcode
end
2012-09-01 17:08:06 -04:00
```
2009-02-07 16:50:06 -05:00
2012-09-03 21:21:24 -04:00
The above code will execute just **2** queries, as opposed to **11** queries in the previous case:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2010-04-05 11:19:48 -04:00
SELECT * FROM clients LIMIT 10
2009-02-07 16:50:06 -05:00
SELECT addresses.* FROM addresses
WHERE (addresses.client_id IN (1,2,3,4,5,6,7,8,9,10))
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Eager Loading Multiple Associations
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
Active Record lets you eager load any number of associations with a single `Model.find` call by using an array, hash, or a nested hash of array/hash with the `includes` method.
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
#### Array of Multiple Associations
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-02-04 14:11:59 -05:00
Post.includes(:category, :comments)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2009-02-07 16:50:06 -05:00
This loads all the posts and the associated category and comments for each post.
2012-09-01 17:25:58 -04:00
#### Nested Associations Hash
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-11-19 07:54:46 -05:00
Category.includes(posts: [{ comments: :guest }, :tags]).find(1)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2010-07-14 05:30:12 -04:00
This will find the category with id 1 and eager load all of the associated posts, the associated posts' tags and comments, and every comment's guest association.
2009-02-07 16:50:06 -05:00
2012-09-01 17:25:58 -04:00
### Specifying Conditions on Eager Loaded Associations
2009-02-07 16:50:06 -05:00
2012-09-02 01:08:20 -04:00
Even though Active Record lets you specify conditions on the eager loaded associations just like `joins` , the recommended way is to use [joins ](#joining-tables ) instead.
2009-02-07 16:50:06 -05:00
2012-09-01 21:37:59 -04:00
However if you must do this, you may use `where` as you would normally.
2011-03-21 21:16:13 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-07-10 23:42:03 -04:00
Post.includes(:comments).where("comments.visible" => true)
2012-09-01 17:08:06 -04:00
```
2011-03-21 21:16:13 -04:00
2012-09-01 21:37:59 -04:00
This would generate a query which contains a `LEFT OUTER JOIN` whereas the `joins` method would generate one using the `INNER JOIN` function instead.
2011-03-21 21:16:13 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-04-06 05:44:47 -04:00
SELECT "posts"."id" AS t0_r0, ... "comments"."updated_at" AS t1_r5 FROM "posts" LEFT OUTER JOIN "comments" ON "comments"."post_id" = "posts"."id" WHERE (comments.visible = 1)
2012-09-01 17:08:06 -04:00
```
2011-03-21 21:16:13 -04:00
2012-09-01 21:37:59 -04:00
If there was no `where` condition, this would generate the normal set of two queries.
2011-03-21 21:16:15 -04:00
2012-09-06 22:26:59 -04:00
If, in the case of this `includes` query, there were no comments for any posts, all the posts would still be loaded. By using `joins` (an INNER JOIN), the join conditions **must** match, otherwise no records will be returned.
2011-03-21 21:16:13 -04:00
2012-09-01 17:25:58 -04:00
Scopes
------
2010-12-22 23:35:17 -05:00
2012-09-01 21:37:59 -04:00
Scoping allows you to specify commonly-used queries which can be referenced as method calls on the association objects or models. With these scopes, you can use every method previously covered such as `where` , `joins` and `includes` . All scope methods will return an `ActiveRecord::Relation` object which will allow for further methods (such as other scopes) to be called on it.
2010-12-22 23:35:17 -05:00
2012-10-26 08:56:37 -04:00
To define a simple scope, we use the `scope` method inside the class, passing the query that we'd like to run when this scope is called:
2010-12-22 23:35:17 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:55:42 -05:00
class Post < ActiveRecord::Base
2012-03-30 08:15:47 -04:00
scope :published, -> { where(published: true) }
2010-12-22 23:55:42 -05:00
end
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:35:17 -05:00
2012-03-30 08:15:47 -04:00
This is exactly the same as defining a class method, and which you use is a matter of personal preference:
2010-12-22 23:35:17 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:55:42 -05:00
class Post < ActiveRecord::Base
2012-03-30 08:15:47 -04:00
def self.published
where(published: true)
end
2010-12-22 23:55:42 -05:00
end
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:35:17 -05:00
Scopes are also chainable within scopes:
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:55:42 -05:00
class Post < ActiveRecord::Base
2012-11-15 15:28:24 -05:00
scope :published, -> { where(published: true) }
2012-04-07 12:23:47 -04:00
scope :published_and_commented, -> { published.where("comments_count > 0") }
2010-12-22 23:55:42 -05:00
end
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:35:17 -05:00
2012-09-01 21:37:59 -04:00
To call this `published` scope we can call it on either the class:
2010-12-22 23:35:17 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-10-05 17:52:50 -04:00
Post.published # => [published posts]
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:35:17 -05:00
2012-09-01 21:37:59 -04:00
Or on an association consisting of `Post` objects:
2010-12-22 23:35:17 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:55:42 -05:00
category = Category.first
2011-10-05 17:52:50 -04:00
category.posts.published # => [published posts belonging to this category]
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:35:17 -05:00
2012-09-01 17:25:58 -04:00
### Passing in arguments
2010-12-22 23:57:53 -05:00
2012-03-30 08:58:51 -04:00
Your scope can take arguments:
2010-12-22 23:57:53 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:57:53 -05:00
class Post < ActiveRecord::Base
2012-03-30 08:15:47 -04:00
scope :created_before, ->(time) { where("created_at < ?", time) }
2010-12-22 23:57:53 -05:00
end
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:57:53 -05:00
2013-09-22 14:07:23 -04:00
Call the scope as if it were a class method:
2010-12-22 23:57:53 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-01-24 13:23:56 -05:00
Post.created_before(Time.zone.now)
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:57:53 -05:00
However, this is just duplicating the functionality that would be provided to you by a class method.
2012-09-01 17:08:06 -04:00
```ruby
2010-12-22 23:57:53 -05:00
class Post < ActiveRecord::Base
2012-01-24 13:23:56 -05:00
def self.created_before(time)
2010-12-22 23:57:53 -05:00
where("created_at < ?", time)
end
end
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:57:53 -05:00
2010-12-22 23:58:33 -05:00
Using a class method is the preferred way to accept arguments for scopes. These methods will still be accessible on the association objects:
2012-09-01 17:08:06 -04:00
```ruby
2012-01-24 13:23:56 -05:00
category.posts.created_before(time)
2012-09-01 17:08:06 -04:00
```
2010-12-22 23:57:53 -05:00
2013-03-08 08:38:43 -05:00
### Merging of scopes
Just like `where` clauses scopes are merged using `AND` conditions.
```ruby
class User < ActiveRecord::Base
scope :active, -> { where state: 'active' }
2013-03-08 08:47:38 -05:00
scope :inactive, -> { where state: 'inactive' }
2013-03-08 08:38:43 -05:00
end
User.active.inactive
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'active' AND "users"."state" = 'inactive'
```
We can mix and match `scope` and `where` conditions and the final sql
will have all conditions joined with `AND` .
```ruby
User.active.where(state: 'finished')
2013-03-08 08:47:38 -05:00
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'active' AND "users"."state" = 'finished'
2013-03-08 08:38:43 -05:00
```
If we do want the `last where clause` to win then `Relation#merge` can
be used .
```ruby
User.active.merge(User.inactive)
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'inactive'
```
One important caveat is that `default_scope` will be overridden by
`scope` and `where` conditions.
```ruby
class User < ActiveRecord::Base
2013-05-28 08:36:18 -04:00
default_scope { where state: 'pending' }
2013-03-08 08:38:43 -05:00
scope :active, -> { where state: 'active' }
2013-03-08 08:47:38 -05:00
scope :inactive, -> { where state: 'inactive' }
2013-03-08 08:38:43 -05:00
end
User.all
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'pending'
User.active
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'active'
User.where(state: 'inactive')
# => SELECT "users".* FROM "users" WHERE "users"."state" = 'inactive'
```
As you can see above the `default_scope` is being overridden by both
2013-03-09 13:36:51 -05:00
`scope` and `where` conditions.
2013-03-08 08:38:43 -05:00
2012-09-01 17:25:58 -04:00
### Applying a default scope
2011-06-26 01:39:12 -04:00
2012-09-08 14:10:40 -04:00
If we wish for a scope to be applied across all queries to the model we can use the
2012-09-01 21:37:59 -04:00
`default_scope` method within the model itself.
2011-06-26 01:39:12 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-06-26 07:36:19 -04:00
class Client < ActiveRecord::Base
2012-03-30 08:15:47 -04:00
default_scope { where("removed_at IS NULL") }
2011-06-26 07:36:19 -04:00
end
2012-09-01 17:08:06 -04:00
```
2011-06-26 01:39:12 -04:00
2012-09-08 14:10:40 -04:00
When queries are executed on this model, the SQL query will now look something like
this:
2011-06-26 01:39:12 -04:00
2012-09-01 17:08:06 -04:00
```sql
2011-06-26 07:36:19 -04:00
SELECT * FROM clients WHERE removed_at IS NULL
2012-09-01 17:08:06 -04:00
```
2011-06-26 01:39:12 -04:00
2012-09-08 14:10:40 -04:00
If you need to do more complex things with a default scope, you can alternatively
define it as a class method:
2012-09-07 11:24:24 -04:00
2012-09-01 17:25:58 -04:00
```ruby
2012-09-07 11:24:24 -04:00
class Client < ActiveRecord::Base
def self.default_scope
2012-09-08 14:10:40 -04:00
# Should return an ActiveRecord::Relation.
2012-09-07 11:24:24 -04:00
end
end
2012-09-01 17:25:58 -04:00
```
2012-09-07 11:24:24 -04:00
2012-12-07 16:31:27 -05:00
### Removing All Scoping
2011-06-26 01:39:12 -04:00
2012-09-01 21:37:59 -04:00
If we wish to remove scoping for any reason we can use the `unscoped` method. This is
especially useful if a `default_scope` is specified in the model and should not be
2012-09-08 14:10:40 -04:00
applied for this particular query.
2011-06-26 01:39:12 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2013-11-15 16:31:23 -05:00
Client.unscoped.load
2012-09-01 17:08:06 -04:00
```
2011-06-26 01:39:12 -04:00
This method removes all scoping and will do a normal query on the table.
2012-09-01 21:37:59 -04:00
Note that chaining `unscoped` with a `scope` does not work. In these cases, it is
recommended that you use the block form of `unscoped` :
2012-09-08 14:10:40 -04:00
2012-09-01 17:25:58 -04:00
```ruby
2012-09-08 14:10:40 -04:00
Client.unscoped {
2013-03-14 00:42:54 -04:00
Client.created_before(Time.zone.now)
2012-09-08 14:10:40 -04:00
}
2012-09-01 17:25:58 -04:00
```
2012-09-08 14:10:40 -04:00
2012-09-01 17:25:58 -04:00
Dynamic Finders
---------------
2009-02-03 20:44:58 -05:00
2013-04-30 11:59:12 -04:00
NOTE: Dynamic finders have been deprecated in Rails 4.0 and will be
removed in Rails 4.1. The best practice is to use Active Record scopes
instead. You can find the deprecation gem at
https://github.com/rails/activerecord-deprecated_finders
2013-04-22 23:02:24 -04:00
2013-01-01 14:36:33 -05:00
For every field (also known as an attribute) you define in your table, Active Record provides a finder method. If you have a field called `first_name` on your `Client` model for example, you get `find_by_first_name` for free from Active Record. If you have a `locked` field on the `Client` model, you also get `find_by_locked` and methods.
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
You can specify an exclamation point (`!`) on the end of the dynamic finders to get them to raise an `ActiveRecord::RecordNotFound` error if they do not return any records, like `Client.find_by_name!("Ryan")`
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to find both by name and locked, you can chain these finders together by simply typing "`and`" between the fields. For example, `Client.find_by_first_name_and_locked("Ryan", true)` .
2009-02-03 20:44:58 -05:00
2012-12-07 16:31:27 -05:00
Find or Build a New Object
2012-09-01 17:25:58 -04:00
--------------------------
2011-08-28 00:10:25 -04:00
2012-10-19 08:18:47 -04:00
It's common that you need to find a record or create it if it doesn't exist. You can do that with the `find_or_create_by` and `find_or_create_by!` methods.
2011-08-28 00:10:25 -04:00
2012-10-19 10:56:18 -04:00
### `find_or_create_by`
2011-08-28 00:10:25 -04:00
2012-10-19 08:18:47 -04:00
The `find_or_create_by` method checks whether a record with the attributes exists. If it doesn't, then `create` is called. Let's see an example.
2011-08-28 00:10:25 -04:00
2012-10-19 08:18:47 -04:00
Suppose you want to find a client named 'Andy', and if there's none, create one. You can do so by running:
2011-08-28 00:10:25 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-10-19 08:18:47 -04:00
Client.find_or_create_by(first_name: 'Andy')
# => #<Client id: 1, first_name: "Andy", orders_count: 0, locked: true, created_at: "2011-08-30 06:09:27", updated_at: "2011-08-30 06:09:27">
2012-09-01 17:08:06 -04:00
```
2011-08-28 00:10:25 -04:00
The SQL generated by this method looks like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```sql
2011-08-28 00:10:25 -04:00
SELECT * FROM clients WHERE (clients.first_name = 'Andy') LIMIT 1
2009-02-03 20:44:58 -05:00
BEGIN
2012-10-19 08:18:47 -04:00
INSERT INTO clients (created_at, first_name, locked, orders_count, updated_at) VALUES ('2011-08-30 05:22:57', 'Andy', 1, NULL, '2011-08-30 05:22:57')
2009-02-03 20:44:58 -05:00
COMMIT
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-10-19 08:18:47 -04:00
`find_or_create_by` returns either the record that already exists or the new record. In our case, we didn't already have a client named Andy so the record is created and returned.
2011-08-28 00:10:25 -04:00
2012-09-01 21:37:59 -04:00
The new record might not be saved to the database; that depends on whether validations passed or not (just like `create` ).
2011-08-28 00:10:25 -04:00
2013-09-26 03:16:20 -04:00
Suppose we want to set the 'locked' attribute to `false` if we're
2012-10-19 08:18:47 -04:00
creating a new record, but we don't want to include it in the query. So
we want to find the client named "Andy", or if that client doesn't
exist, create a client named "Andy" which is not locked.
2011-08-28 00:10:25 -04:00
2012-10-26 08:56:37 -04:00
We can achieve this in two ways. The first is to use `create_with` :
2012-10-19 10:56:18 -04:00
```ruby
Client.create_with(locked: false).find_or_create_by(first_name: 'Andy')
```
The second way is using a block:
2011-09-14 13:35:29 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-10-19 08:18:47 -04:00
Client.find_or_create_by(first_name: 'Andy') do |c|
c.locked = false
end
```
The block will only be executed if the client is being created. The
second time we run this code, the block will be ignored.
2012-10-19 10:56:18 -04:00
### `find_or_create_by!`
2012-10-19 08:18:47 -04:00
You can also use `find_or_create_by!` to raise an exception if the new record is invalid. Validations are not covered on this guide, but let's assume for a moment that you temporarily add
2011-08-28 00:10:25 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
validates :orders_count, presence: true
2012-09-01 17:08:06 -04:00
```
2011-08-28 00:10:25 -04:00
2012-09-01 21:37:59 -04:00
to your `Client` model. If you try to create a new `Client` without passing an `orders_count` , the record will be invalid and an exception will be raised:
2011-08-28 00:10:25 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-10-19 08:18:47 -04:00
Client.find_or_create_by!(first_name: 'Andy')
2011-10-06 16:29:58 -04:00
# => ActiveRecord::RecordInvalid: Validation failed: Orders count can't be blank
2012-09-01 17:08:06 -04:00
```
2011-08-28 00:10:25 -04:00
2012-10-19 10:56:18 -04:00
### `find_or_initialize_by`
2011-08-28 00:10:25 -04:00
2012-10-19 08:18:47 -04:00
The `find_or_initialize_by` method will work just like
`find_or_create_by` but it will call `new` instead of `create` . This
means that a new model instance will be created in memory but won't be
saved to the database. Continuing with the `find_or_create_by` example, we
now want the client named 'Nick':
2011-08-28 00:10:25 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-10-19 08:18:47 -04:00
nick = Client.find_or_initialize_by(first_name: 'Nick')
# => <Client id: nil, first_name: "Nick", orders_count: 0, locked: true, created_at: "2011-08-30 06:09:27", updated_at: "2011-08-30 06:09:27">
2011-08-28 00:10:25 -04:00
nick.persisted?
2011-10-06 16:29:58 -04:00
# => false
2011-08-28 00:10:25 -04:00
nick.new_record?
2011-10-06 16:29:58 -04:00
# => true
2012-09-01 17:08:06 -04:00
```
2011-08-28 00:10:25 -04:00
Because the object is not yet stored in the database, the SQL generated looks like this:
2012-09-01 17:08:06 -04:00
```sql
2011-08-28 00:10:25 -04:00
SELECT * FROM clients WHERE (clients.first_name = 'Nick') LIMIT 1
2012-09-01 17:08:06 -04:00
```
2011-08-28 00:10:25 -04:00
2012-09-01 21:37:59 -04:00
When you want to save it to the database, just call `save` :
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-08-28 00:10:25 -04:00
nick.save
2011-10-06 16:29:58 -04:00
# => true
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
Finding by SQL
--------------
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you'd like to use your own SQL to find records in a table you can use `find_by_sql` . The `find_by_sql` method will return an array of objects even if the underlying query returns just a single record. For example you could run this query:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-14 01:13:00 -04:00
Client.find_by_sql("SELECT * FROM clients
INNER JOIN orders ON clients.id = orders.client_id
2009-02-09 19:49:17 -05:00
ORDER clients.created_at desc")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
`find_by_sql` provides you with a simple way of making custom calls to the database and retrieving instantiated objects.
2009-02-03 20:44:58 -05:00
2012-09-03 21:21:24 -04:00
### `select_all`
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
`find_by_sql` has a close relative called `connection#select_all` . `select_all` will retrieve objects from the database using custom SQL just like `find_by_sql` but will not instantiate them. Instead, you will get an array of hashes where each hash indicates a record.
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.connection.select_all("SELECT * FROM clients WHERE id = '1'")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-03 21:21:24 -04:00
### `pluck`
2011-11-30 04:03:00 -05:00
2012-09-01 19:34:21 -04:00
`pluck` can be used to query a single or multiple columns from the underlying table of a model. It accepts a list of column names as argument and returns an array of values of the specified columns with the corresponding data type.
2011-11-30 04:03:00 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(active: true).pluck(:id)
2011-11-30 14:53:19 -05:00
# SELECT id FROM clients WHERE active = 1
2012-06-22 08:30:00 -04:00
# => [1, 2, 3]
2011-11-30 14:53:19 -05:00
2013-03-12 05:23:08 -04:00
Client.distinct.pluck(:role)
2011-11-30 14:53:19 -05:00
# SELECT DISTINCT role FROM clients
2012-06-22 08:30:00 -04:00
# => ['admin', 'member', 'guest']
Client.pluck(:id, :name)
# SELECT clients.id, clients.name FROM clients
# => [[1, 'David'], [2, 'Jeremy'], [3, 'Jose']]
2012-09-01 17:08:06 -04:00
```
2011-11-30 14:53:19 -05:00
2013-09-04 05:04:36 -04:00
`pluck` makes it possible to replace code like:
2011-11-30 14:53:19 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-11-30 14:53:19 -05:00
Client.select(:id).map { |c| c.id }
2012-06-22 08:30:00 -04:00
# or
2012-11-08 08:44:35 -05:00
Client.select(:id).map(& :id)
# or
2013-03-07 13:05:27 -05:00
Client.select(:id, :name).map { |c| [c.id, c.name] }
2012-09-01 17:08:06 -04:00
```
2011-11-30 14:53:19 -05:00
2013-09-04 05:04:36 -04:00
with:
2011-11-30 14:53:19 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2011-11-30 14:53:19 -05:00
Client.pluck(:id)
2012-06-22 08:30:00 -04:00
# or
Client.pluck(:id, :name)
2012-09-01 17:08:06 -04:00
```
2012-05-16 16:02:21 -04:00
2013-09-04 05:04:36 -04:00
Unlike `select` , `pluck` directly converts a database result into a Ruby `Array` ,
without constructing `ActiveRecord` objects. This can mean better performance for
a large or often-running query. However, any model method overrides will
not be available. For example:
```ruby
class Client < ActiveRecord::Base
def name
"I am #{super}"
end
end
Client.select(:name).map & :name
# => ["I am David", "I am Jeremy", "I am Jose"]
Client.pluck(:name)
# => ["David", "Jeremy", "Jose"]
```
Furthermore, unlike `select` and other `Relation` scopes, `pluck` triggers an immediate
query, and thus cannot be chained with any further scopes, although it can work with
scopes already constructed earlier:
```ruby
Client.pluck(:name).limit(1)
# => NoMethodError: undefined method `limit' for #<Array:0x007ff34d3ad6d8>
Client.limit(1).pluck(:name)
# => ["David"]
```
2012-09-03 21:21:24 -04:00
### `ids`
2012-05-16 16:02:21 -04:00
2012-09-01 21:37:59 -04:00
`ids` can be used to pluck all the IDs for the relation using the table's primary key.
2012-05-16 16:02:21 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-16 16:02:21 -04:00
Person.ids
# SELECT id FROM people
2012-09-01 17:08:06 -04:00
```
2012-05-16 16:02:21 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2012-05-16 16:02:21 -04:00
class Person < ActiveRecord::Base
self.primary_key = "person_id"
end
Person.ids
# SELECT person_id FROM people
2012-09-01 17:08:06 -04:00
```
2011-11-30 04:03:00 -05:00
2012-09-01 17:25:58 -04:00
Existence of Objects
--------------------
2009-02-03 20:44:58 -05:00
2013-09-04 19:48:15 -04:00
If you simply want to check for the existence of the object there's a method called `exists?` .
This method will query the database using the same query as `find` , but instead of returning an
object or collection of objects it will return either `true` or `false` .
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.exists?(1)
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2013-09-04 19:48:15 -04:00
The `exists?` method also takes multiple values, but the catch is that it will return `true` if any
one of those records exists.
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-09-04 19:48:15 -04:00
Client.exists?(id: [1,2,3])
2009-02-03 20:44:58 -05:00
# or
2013-09-04 19:48:15 -04:00
Client.exists?(name: ['John', 'Sergei'])
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
It's even possible to use `exists?` without any arguments on a model or a relation.
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(first_name: 'Ryan').exists?
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2013-09-04 19:48:15 -04:00
The above returns `true` if there is at least one client with the `first_name` 'Ryan' and `false`
otherwise.
2009-02-09 19:49:17 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-09 19:49:17 -05:00
Client.exists?
2012-09-01 17:08:06 -04:00
```
2009-02-09 19:49:17 -05:00
2012-09-01 21:37:59 -04:00
The above returns `false` if the `clients` table is empty and `true` otherwise.
2009-02-09 19:49:17 -05:00
2012-09-01 21:37:59 -04:00
You can also use `any?` and `many?` to check for existence on a model or relation.
2011-03-29 10:08:40 -04:00
2012-09-01 17:08:06 -04:00
```ruby
2011-03-29 10:08:40 -04:00
# via a model
Post.any?
Post.many?
# via a named scope
Post.recent.any?
Post.recent.many?
# via a relation
2012-11-15 15:28:24 -05:00
Post.where(published: true).any?
Post.where(published: true).many?
2011-03-29 10:08:40 -04:00
# via an association
Post.first.categories.any?
Post.first.categories.many?
2012-09-01 17:08:06 -04:00
```
2011-03-29 10:08:40 -04:00
2012-09-01 17:25:58 -04:00
Calculations
------------
2009-02-03 20:44:58 -05:00
This section uses count as an example method in this preamble, but the options described apply to all sub-sections.
2010-08-30 18:44:51 -04:00
All calculation methods work directly on a model:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2010-08-30 18:44:51 -04:00
Client.count
# SELECT count(*) AS count_all FROM clients
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2011-04-13 20:58:26 -04:00
Or on a relation:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
Client.where(first_name: 'Ryan').count
2010-08-30 18:44:51 -04:00
# SELECT count(*) AS count_all FROM clients WHERE (first_name = 'Ryan')
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2010-08-30 18:44:51 -04:00
You can also use various finder methods on a relation for performing complex calculations:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2013-11-19 07:54:46 -05:00
Client.includes("orders").where(first_name: 'Ryan', orders: { status: 'received' }).count
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
Which will execute:
2012-09-01 17:08:06 -04:00
```sql
2009-02-03 20:44:58 -05:00
SELECT count(DISTINCT clients.id) AS count_all FROM clients
LEFT OUTER JOIN orders ON orders.client_id = client.id WHERE
(clients.first_name = 'Ryan' AND orders.status = 'received')
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Count
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to see how many records are in your model's table you could call `Client.count` and that will return the number. If you want to be more specific and find all the clients with their age present in the database you can use `Client.count(:age)` .
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
For options, please see the parent section, [Calculations ](#calculations ).
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Average
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to see the average of a certain number in one of your tables you can call the `average` method on the class that relates to the table. This method call will look something like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.average("orders_count")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
This will return a number (possibly a floating point number such as 3.14159265) representing the average value in the field.
2012-09-02 01:08:20 -04:00
For options, please see the parent section, [Calculations ](#calculations ).
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Minimum
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to find the minimum value of a field in your table you can call the `minimum` method on the class that relates to the table. This method call will look something like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.minimum("age")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
For options, please see the parent section, [Calculations ](#calculations ).
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Maximum
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to find the maximum value of a field in your table you can call the `maximum` method on the class that relates to the table. This method call will look something like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.maximum("age")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
For options, please see the parent section, [Calculations ](#calculations ).
2009-02-03 20:44:58 -05:00
2012-09-01 17:25:58 -04:00
### Sum
2009-02-03 20:44:58 -05:00
2012-09-01 21:37:59 -04:00
If you want to find the sum of a field for all records in your table you can call the `sum` method on the class that relates to the table. This method call will look something like this:
2009-02-03 20:44:58 -05:00
2012-09-01 17:08:06 -04:00
```ruby
2009-02-03 20:44:58 -05:00
Client.sum("orders_count")
2012-09-01 17:08:06 -04:00
```
2009-02-03 20:44:58 -05:00
2012-09-02 01:08:20 -04:00
For options, please see the parent section, [Calculations ](#calculations ).
2011-09-20 13:50:08 -04:00
2012-09-01 17:25:58 -04:00
Running EXPLAIN
---------------
2011-09-20 13:50:08 -04:00
You can run EXPLAIN on the queries triggered by relations. For example,
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
User.where(id: 1).joins(:posts).explain
2012-09-01 17:08:06 -04:00
```
2011-09-20 13:50:08 -04:00
may yield
2012-09-01 17:08:06 -04:00
```
2011-11-25 17:29:34 -05:00
EXPLAIN for: SELECT `users` .* FROM `users` INNER JOIN `posts` ON `posts` .`user_id` = `users` .`id` WHERE `users` .`id` = 1
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
2011-09-20 13:50:08 -04:00
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
2011-09-20 13:50:08 -04:00
| 1 | SIMPLE | users | const | PRIMARY | PRIMARY | 4 | const | 1 | |
| 1 | SIMPLE | posts | ALL | NULL | NULL | NULL | NULL | 1 | Using where |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------------+
2011-09-20 13:50:08 -04:00
2 rows in set (0.00 sec)
2012-09-01 17:08:06 -04:00
```
2011-09-20 13:50:08 -04:00
under MySQL.
Active Record performs a pretty printing that emulates the one of the database
2011-11-06 08:28:55 -05:00
shells. So, the same query running with the PostgreSQL adapter would yield instead
2011-09-20 13:50:08 -04:00
2012-09-01 17:08:06 -04:00
```
2011-11-25 17:29:34 -05:00
EXPLAIN for: SELECT "users".* FROM "users" INNER JOIN "posts" ON "posts"."user_id" = "users"."id" WHERE "users"."id" = 1
2011-09-20 13:50:08 -04:00
QUERY PLAN
------------------------------------------------------------------------------
Nested Loop Left Join (cost=0.00..37.24 rows=8 width=0)
Join Filter: (posts.user_id = users.id)
-> Index Scan using users_pkey on users (cost=0.00..8.27 rows=1 width=4)
Index Cond: (id = 1)
-> Seq Scan on posts (cost=0.00..28.88 rows=8 width=4)
Filter: (posts.user_id = 1)
(6 rows)
2012-09-01 17:08:06 -04:00
```
2011-09-20 13:50:08 -04:00
Eager loading may trigger more than one query under the hood, and some queries
2012-09-01 21:37:59 -04:00
may need the results of previous ones. Because of that, `explain` actually
2011-09-20 13:50:08 -04:00
executes the query, and then asks for the query plans. For example,
2012-09-01 17:08:06 -04:00
```ruby
2012-11-15 15:28:24 -05:00
User.where(id: 1).includes(:posts).explain
2012-09-01 17:08:06 -04:00
```
2011-09-20 13:50:08 -04:00
yields
2012-09-01 17:08:06 -04:00
```
2011-11-25 17:29:34 -05:00
EXPLAIN for: SELECT `users` .* FROM `users` WHERE `users` .`id` = 1
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------+
2011-09-20 13:50:08 -04:00
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------+
2011-09-20 13:50:08 -04:00
| 1 | SIMPLE | users | const | PRIMARY | PRIMARY | 4 | const | 1 | |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+-------+---------------+---------+---------+-------+------+-------+
2011-09-20 13:50:08 -04:00
1 row in set (0.00 sec)
2011-11-25 17:29:34 -05:00
EXPLAIN for: SELECT `posts` .* FROM `posts` WHERE `posts` .`user_id` IN (1)
2012-09-03 21:21:24 -04:00
+----+-------------+-------+------+---------------+------+---------+------+------+-------------+
2011-09-20 13:50:08 -04:00
| id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+------+---------------+------+---------+------+------+-------------+
2011-09-20 13:50:08 -04:00
| 1 | SIMPLE | posts | ALL | NULL | NULL | NULL | NULL | 1 | Using where |
2012-09-03 21:21:24 -04:00
+----+-------------+-------+------+---------------+------+---------+------+------+-------------+
2011-09-20 13:50:08 -04:00
1 row in set (0.00 sec)
2012-09-01 17:08:06 -04:00
```
2011-09-20 13:50:08 -04:00
under MySQL.
2011-11-25 17:58:43 -05:00
2012-09-01 17:25:58 -04:00
### Interpreting EXPLAIN
2011-11-25 17:58:43 -05:00
Interpretation of the output of EXPLAIN is beyond the scope of this guide. The
following pointers may be helpful:
2012-09-02 01:08:20 -04:00
* SQLite3: [EXPLAIN QUERY PLAN ](http://www.sqlite.org/eqp.html )
2011-11-25 17:58:43 -05:00
2012-09-02 01:08:20 -04:00
* MySQL: [EXPLAIN Output Format ](http://dev.mysql.com/doc/refman/5.6/en/explain-output.html )
2011-11-25 17:58:43 -05:00
2012-09-02 01:08:20 -04:00
* PostgreSQL: [Using EXPLAIN ](http://www.postgresql.org/docs/current/static/using-explain.html )