- 9.1 Scopes
- 9.2 Callbacks
- 9.3 Calculation Methods
- 9.4 Single-Table Inheritance (STI)
- 9.5 Abstract Base Model Classes
- 9.6 Polymorphic has_many Relationships
- 9.7 Enums
- 9.8 Foreign-Key Constraints
- 9.9 Modules for Reusing Common Behavior
- 9.10 Modifying Active Record Classes at Runtime
- 9.11 Using Value Objects
- 9.12 Nonpersisted Models
- 9.13 PostgreSQL Enhancements
- 9.14 Conclusion
9.13 PostgreSQL Enhancements
Out of all the supported databases available in Active Record, PostgreSQL received the most amount of attention during the development of Rails 4. In this section, we are going to look at the various additions made to the PostgreSQL database adapter.
9.13.1 Schemaless Data with hstore
The hstore data type from PostgreSQL allows for the storing of key/value pairs or simply a hash within a single column. In other words, if you are using PostgreSQL and Rails 4, you can now have schema-less data within your models.
To get started, first set up your PostgreSQL database to use the hstore extension via the enable_extension migration method:
1 class AddHstoreExtension < ActiveRecord::Migration
2 def change
3 enable_extension "hstore"
4 end
5 end
Next, add the hstore column type to a model. For the purpose of our examples, we will be using a Photo model with an hstore attribute properties.
1 class AddPropertiesToPhotos < ActiveRecord::Migration
2 change_table :photos do |t|
3 t.hstore :properties
4 end
5 end
With the hstore column properties set up, we are able to write a hash to the database:
1 photo = Photo.new
2 photo.properties # nil
3 photo.properties = { aperture: 'f/4.5', shutter_speed: '1/100 secs' }
4 photo.save && photo.reload
5 photo.properties # {:aperture=>"f/4.5", :shutter_speed=>"1/100 secs"}
Although this works well enough, Active Record does not keep track of any changes made to the properties attribute itself.
1 photo.properties[:taken] = Time.current
2 photo.properties
3 # {:aperture=>"f/4.5", :shutter_speed=>"1/100 secs",
4 # :taken=>Wed, 23 Oct 2013 16:03:35 UTC +00:00}
5
6 photo.save && photo.reload
7 photo.properties # {:aperture=>"f/4.5", :shutter_speed=>"1/100 secs"}
As with some other PostgreSQL column types, such as array and json, you must tell Active Record that a change has taken place via the <attribute>_will_change! method. However, a better solution is to use the Active Record store_accessor macro-style method to add read/write accessors to hstore values.
1 class Photo < ActiveRecord::Base
2 store_accessor :properties, :aperture, :shutter_speed
3 end
When we set new values to any of these accessors, Active Record is able to track the changes made to the underlying hash, eliminating the need to call the <attribute>_will_change! method. Like any accessor, they can have Active Model validations added to them and also can be used in forms.
1 photo = Photo.new
2 photo.aperture = "f/4.5"
3 photo.shutter_speed = "1/100 secs"
4 photo.properties # {"aperture"=>"f/4.5", "shutter_speed"=>"1/100 secs"}
5
6 photo.save && photo.reload
7
8 photo.properties # {"aperture"=>"f/4.5", "shutter_speed"=>"1/100 secs"}
9 photo.aperture = "f/1.4"
10
11 photo.save && photo.reload
12 photo.properties # {"aperture"=>"f/1.4", "shutter_speed"=>"1/100 secs"}
Be aware that when an hstore attribute is returned from PostgreSQL, all key/values will be strings.
9.13.1.1 Querying hstore
To query against an hstore value in Active Record, use SQL string conditions with the where query method. For the sake of clarity, here are a couple examples of various queries that can be made against an hstore column type:
1 # Nonindexed query to find all photos that have a key 'aperture' with a
2 # value of f/1.4
3 Photo.where("properties -> :key = :value", key: 'aperture', value: 'f/1.4')
4
5 # Indexed query to find all photos that have a key 'aperture' with a value
6 # of f/1.4
7 Photo.where("properties @> 'aperture=>f/1.4'")
8
9 # All photos that have a key 'aperture' in properties
10 Photo.where("properties ? :key", key: 'aperture')
11
12 # All photos that do not have a key 'aperture' in properties
13 Photo.where("not properties ? :key", key: 'aperture')
14
15 # All photos that contains all keys 'aperture' and 'shutter_speed'
16 Photo.where("properties ?& ARRAY[:keys]", keys: %w(aperture shutter_speed))
17
18 # All photos that contains any of the keys 'aperture' or 'shutter_speed'
19 Photo.where("properties ?| ARRAY[:keys]", keys: %w(aperture shutter_speed))
For more information on how to build hstore queries, you can consult the PostgreSQL documentation directly.16
9.13.1.2 GiST and GIN Indexes
If you are doing any queries on an hstore column type, be sure to add the appropriate index. When adding an index, you will have to decide to use either GIN or GiST index types. The distinguishing factor between the two index types is that GIN index lookups are three times faster than GiST indexes; however, they also take three times longer to build.
You can define either a GIN or GiST index using Active Record migrations by setting the index option :using to :gin or :gist, respectively.
add_index :photos, :properties, using: :gin
# or
add_index :photos, :properties, using: :gist
GIN and GiST indexes support queries with @>, ?, ?&, and ?| operators.
9.13.2 Array Type
Another NoSQL-like column type supported by PostgreSQL and Rails 4 is array. This allows us to store a collection of a data type, such as strings, within the database record itself. For instance, assuming we had an Article model, we could store all the article’s tags in an array attribute named tags. Since the tags are not stored in another table, when Active Record retrieves an article from the database, it does so in a single query.
To declare a column as an array, pass true to the :array option for a column type such as string:
1 class AddTagsToArticles < ActiveRecord::Migration
2 def change
3 change_table :articles do |t|
4 t.string :tags, array: true
5 end
6 end
7 end
8 # ALTER TABLE "articles" ADD COLUMN "tags" character varying(255)[]
The array column type will also accept the option :length to limit the amount of items allowed in the array.
t.string :tags, array: true, length: 10
To set a default value for an array column, you must use the PostgreSQL array notation ({value}). Setting the default option to {} ensures that every row in the database will default to an empty array.
t.string :tags, array: true, default: '{rails,ruby}'
The migration in the previous code sample would create an array of strings that defaults every row in the database to have an array containing strings “rails” and “ruby.”
>> article = Article.create
(0.1ms) BEGIN
SQL (66.2ms) INSERT INTO "articles" ("created_at", "updated_at") VALUES
($1, $2) RETURNING "id" [["created_at", Wed, 23 Oct 2013 15:03:12
>> article.tags
=> ["rails", "ruby"]
Note that Active Record does not track destructive or in-place changes to the Array instance.
1 article.tags.pop
2 article.tags # ["rails"]
3 article.save && article.reload
4 article.tags # ["rails", "ruby"]
To ensure changes are persisted, you must tell Active Record that the attribute has changed by calling <attribute>_will_change!.
1 article.tags.pop
2 article.tags # ["rails"]
3 article.tags_will_change!
4 article.save && article.reload
5 article.tags # ["rails"]
If the pg_array_parser gem is included in the application Gemfile, Rails will use it when parsing PostgreSQL’s array representation. The gem includes a native C extension and JRuby support.
9.13.2.1 Searching in Arrays
If you wish to query against an array column using Active Record, you must use PSQL’s methods ANY and ALL. To demonstrate, given our previous example, using the ANY method, we could query for any articles that have the tag “rails”:
Article.where("'rails' = ANY(tags)")
Alternatively, the ALL method searches for arrays where all values in the array equal the value specified.
Article.where("'rails' = ALL(tags)")
As with the hstore column type, if you are doing queries against an array column type, the column should be indexed with either GiST or GIN.
add_index :articles, :tags, using: 'gin'
9.13.3 Network Address Types
PostgreSQL comes with column types exclusively for IPv4, IPv6, and MAC addresses. IPv4 or IPv6 host address are represented with Active Record data types inet and cidr, where the former accepts values with nonzero bits to the right of the netmask. When Active Record retrieves inet/cidr data types from the database, it converts the values to IPAddr objects. MAC addresses are represented with the macaddr data type, which are represented as a string in Ruby.
To set a column as a network address in an Active Record migration, set the data type of the column to inet, cidr, or macaddr:
1 class CreateNetworkAddresses < ActiveRecord::Migration
2 def change
3 create_table :network_addresses do |t|
4 t.inet :inet_address
5 t.cidr :cidr_address
6 t.macaddr :mac_address
7 end
8 end
9 end
Setting an inet or cidr type to an invalid network address will result in an IPAddr::InvalidAddressError exception being raised. If an invalid MAC address is set, an error will occur at the database level resulting in an ActiveRecord::StatementInvalid: PG::InvalidTextRepresentation exception being raised.
>> address = NetworkAddress.new
=> #<NetworkAddress id: nil, inet_address: nil, ...>
>> address.inet_address = 'abc'
IPAddr::InvalidAddressError: invalid address
>> address.inet_address = "127.0.0.1"
=> "127.0.0.1"
>> address.inet_address
=> #<IPAddr: IPv4:127.0.0.1/255.255.255.255>
>> address.save && address.reload
=> #<NetworkAddress id: 1,
inet_address: #<IPAddr: IPv4:127.0.0.1/255.255.255.255>, ...>
9.13.4 UUID Type
The uuid column type represents a universally unique identifier (UUID), a 128-bit value that is generated by an algorithm that makes it highly unlikely that the same value can be generated twice.
To set a column as a UUID in an Active Record migration, set the type of the column to uuid:
add_column :table_name, :unique_identifier, :uuid
When reading and writing to a UUID attribute, you will always be dealing with a Ruby string:
record.unique_identifier = 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11'
If an invalid UUID is set, an error will occur at the database level, resulting in an ActiveRecord::StatementInvalid: PG::InvalidTextRepresentation exception being raised.
9.13.5 Range Types
If you have ever needed to store a range of values, Active Record now supports PostgreSQL range types. These ranges can be created with both inclusive and exclusive bounds. The following range types are natively supported:
- daterange
- int4range
- int8range
- numrange
- tsrange
- tstzrange
To illustrate, consider a scheduling application that stores a date range representing the availability of a room.
1 class CreateRooms < ActiveRecord::Migration
2 def change
3 create_table :rooms do |t|
4 t.daterange :availability
5 end
6 end
7 end
8
9 room = Room.create(availability: Date.today..Float::INFINITY)
10 room.reload
11 room.availability # Tue, 22 Oct 2013...Infinity
12 room.availability.class # Range
Note that the Range class does not support exclusive lower bound. For more detailed information about the PostgreSQL range types, consult the official documentation.17
9.13.6 JSON Type
Introduced in PostgreSQL 9.2, the json column type adds the ability for PostgreSQL to store JSON structured data directly in the database. When an Active Record object has an attribute with the type of json, the encoding/decoding of the JSON itself is handled behind the scenes by ActiveSupport::JSON. This allows you to set the attribute to a hash or already encoded JSON string. If you attempt to set the JSON attribute to a string that cannot be decoded, a JSON::ParserError will be raised.
To set a column as JSON in an Active Record migration, set the data type of the column to json:
add_column :users, :preferences, :json
To demonstrate, let’s play with the preferences attribute from the previous example in the console. To begin, I’ll create a user with the color preference of blue.
>> user = User.create(preferences: { color: "blue"} )
(0.2ms) BEGIN
SQL (1.1ms) INSERT INTO "users" ("preferences") VALUES ($1) RETURNING
"id" [["preferences", {:color=>"blue"}]]
(0.4ms) COMMIT
=> #<User id: 1, preferences: {:color=>"blue"}>
Next up, let’s verify when we retrieve the user from the database that the preferences attribute doesn’t return a JSON string but a hash representation instead.
>> user.reload
User Load (10.7ms) SELECT "users".* FROM "users" WHERE "users"."id" = $1
LIMIT 1 [["id", 1]]
=> #<User id: 1, preferences: {"color"=>"blue"}>
>> user.preferences.class
=> Hash
It’s important to note that like the array data type, Active Record does not track in place changes. This means that updating the existing hash does not persist the changes to the database. To ensure changes are persisted, you must call <attribute>_will_change! (preferences_will_change! in our previous example) or completely replace the object instance with a new value instead.