2018-07-23 22:29:31 -04:00
**DO NOT READ THIS FILE ON GITHUB, GUIDES ARE PUBLISHED ON https://guides.rubyonrails.org.**
2014-12-23 17:32:50 -05:00
2014-05-06 07:20:32 -04:00
Active Record and PostgreSQL
2014-01-21 06:13:11 -05:00
============================
2014-05-06 07:20:32 -04:00
This guide covers PostgreSQL specific usage of Active Record.
2014-01-21 06:13:11 -05:00
2014-05-07 01:47:39 -04:00
After reading this guide, you will know:
* How to use PostgreSQL's datatypes.
2014-05-08 05:27:35 -04:00
* How to use UUID primary keys.
* How to implement full text search with PostgreSQL.
2014-06-14 05:20:58 -04:00
* How to back your Active Record models with database views.
2014-05-07 01:47:39 -04:00
--------------------------------------------------------------------------------
2018-09-23 00:45:19 -04:00
In order to use the PostgreSQL adapter you need to have at least version 9.3
2014-05-19 03:14:58 -04:00
installed. Older versions are not supported.
To get started with PostgreSQL have a look at the
[configuring Rails guide ](configuring.html#configuring-a-postgresql-database ).
2019-08-09 17:30:15 -04:00
It describes how to properly set up Active Record for PostgreSQL.
2014-05-19 03:14:58 -04:00
2014-01-21 06:13:11 -05:00
Datatypes
---------
PostgreSQL offers a number of specific datatypes. Following is a list of types,
that are supported by the PostgreSQL adapter.
### Bytea
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-binary.html )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-binarystring.html )
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20140207133952_create_documents.rb
create_table :documents do |t|
t.binary 'payload'
end
2020-12-23 17:29:10 -05:00
```
2014-01-21 06:13:11 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/document.rb
2015-12-12 08:25:00 -05:00
class Document < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-12-23 17:29:10 -05:00
```
2014-01-21 06:13:11 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-01-21 06:13:11 -05:00
# Usage
data = File.read(Rails.root + "tmp/output.pdf")
Document.create payload: data
```
### Array
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/arrays.html )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-array.html )
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20140207133952_create_books.rb
2014-06-09 06:58:36 -04:00
create_table :books do |t|
2014-01-21 06:13:11 -05:00
t.string 'title'
t.string 'tags', array: true
t.integer 'ratings', array: true
end
2014-06-09 06:58:36 -04:00
add_index :books, :tags, using: 'gin'
add_index :books, :ratings, using: 'gin'
2020-12-23 17:29:10 -05:00
```
2014-01-21 06:13:11 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/book.rb
2015-12-12 08:25:00 -05:00
class Book < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-12-23 17:29:10 -05:00
```
2014-01-21 06:13:11 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-01-21 06:13:11 -05:00
# Usage
Book.create title: "Brave New World",
tags: ["fantasy", "fiction"],
ratings: [4, 5]
## Books for a single tag
Book.where("'fantasy' = ANY (tags)")
## Books for multiple tags
Book.where("tags @> ARRAY[?]::varchar[]", ["fantasy", "fiction"])
## Books with 3 or more ratings
Book.where("array_length(ratings, 1) >= 3")
```
### Hstore
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/hstore.html )
2018-03-04 03:50:39 -05:00
* [functions and operators ](https://www.postgresql.org/docs/current/static/hstore.html#id-1.11.7.26.5 )
2014-01-21 06:13:11 -05:00
2015-10-13 16:50:19 -04:00
NOTE: You need to enable the `hstore` extension to use hstore.
2014-12-06 18:54:41 -05:00
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20131009135255_create_profiles.rb
ActiveRecord::Schema.define do
2014-12-06 18:54:41 -05:00
enable_extension 'hstore' unless extension_enabled?('hstore')
2014-01-21 06:13:11 -05:00
create_table :profiles do |t|
t.hstore 'settings'
end
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/profile.rb
2015-12-12 08:25:00 -05:00
class Profile < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Profile.create(settings: { "color" => "blue", "resolution" => "800x600" })
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> profile = Profile.first
irb> profile.settings
=> {"color"=>"blue", "resolution"=>"800x600"}
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> profile.settings = {"color" => "yellow", "resolution" => "1280x1024"}
irb> profile.save!
2016-01-18 00:59:36 -05:00
2020-10-31 17:44:05 -04:00
irb> Profile.where("settings->'color' = ?", "yellow")
=> #< ActiveRecord::Relation [ # < Profile id: 1 , settings: { " color " = > "yellow", "resolution"=>"1280x1024"}>]>
2014-01-21 06:13:11 -05:00
```
2017-06-27 05:10:26 -04:00
### JSON and JSONB
2014-01-21 06:13:11 -05:00
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-json.html )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-json.html )
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20131220144913_create_events.rb
2017-06-27 05:10:26 -04:00
# ... for json datatype:
2014-01-21 06:13:11 -05:00
create_table :events do |t|
t.json 'payload'
end
2017-06-27 05:10:26 -04:00
# ... or for jsonb datatype:
create_table :events do |t|
t.jsonb 'payload'
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/event.rb
2015-12-12 08:25:00 -05:00
class Event < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Event.create(payload: { kind: "user_renamed", change: ["jack", "john"]})
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> event = Event.first
irb> event.payload
=> {"kind"=>"user_renamed", "change"=>["jack", "john"]}
2014-01-21 06:13:11 -05:00
## Query based on JSON document
2014-09-02 17:01:00 -04:00
# The -> operator returns the original JSON type (which might be an object), whereas ->> returns text
2020-10-31 17:44:05 -04:00
irb> Event.where("payload->>'kind' = ?", "user_renamed")
2014-01-21 06:13:11 -05:00
```
### Range Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/rangetypes.html )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-range.html )
2014-01-21 06:13:11 -05:00
2021-02-04 11:34:53 -05:00
This type is mapped to Ruby [`Range` ](https://ruby-doc.org/core-2.7.0/Range.html ) objects.
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20130923065404_create_events.rb
create_table :events do |t|
t.daterange 'duration'
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/event.rb
2015-12-12 08:25:00 -05:00
class Event < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Event.create(duration: Date.new(2014, 2, 11)..Date.new(2014, 2, 12))
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> event = Event.first
irb> event.duration
=> Tue, 11 Feb 2014...Thu, 13 Feb 2014
2014-01-21 06:13:11 -05:00
## All Events on a given date
2020-10-31 17:44:05 -04:00
irb> Event.where("duration @> ?::date", Date.new(2014, 2, 12))
2014-01-21 06:13:11 -05:00
## Working with range bounds
2020-10-31 17:44:05 -04:00
irb> event = Event.select("lower(duration) AS starts_at").select("upper(duration) AS ends_at").first
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> event.starts_at
=> Tue, 11 Feb 2014
irb> event.ends_at
=> Thu, 13 Feb 2014
2014-01-21 06:13:11 -05:00
```
### Composite Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/rowtypes.html )
2014-01-21 06:13:11 -05:00
2014-05-18 12:58:50 -04:00
Currently there is no special support for composite types. They are mapped to
2014-01-21 06:13:11 -05:00
normal text columns:
```sql
CREATE TYPE full_address AS
(
city VARCHAR(90),
street VARCHAR(90)
);
```
```ruby
# db/migrate/20140207133952_create_contacts.rb
execute < < -SQL
2020-12-25 12:17:01 -05:00
CREATE TYPE full_address AS
(
city VARCHAR(90),
street VARCHAR(90)
);
2014-01-21 06:13:11 -05:00
SQL
create_table :contacts do |t|
t.column :address, :full_address
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/contact.rb
2015-12-12 08:25:00 -05:00
class Contact < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Contact.create address: "(Paris,Champs-Élysées)"
irb> contact = Contact.first
irb> contact.address
=> "(Paris,Champs-Élysées)"
irb> contact.address = "(Paris,Rue Basse)"
irb> contact.save!
2014-01-21 06:13:11 -05:00
```
### Enumerated Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-enum.html )
2014-01-21 06:13:11 -05:00
Currently there is no special support for enumerated types. They are mapped as
normal text columns:
```ruby
2014-11-22 02:13:33 -05:00
# db/migrate/20131220144913_create_articles.rb
2015-07-22 11:52:24 -04:00
def up
execute < < -SQL
CREATE TYPE article_status AS ENUM ('draft', 'published');
SQL
create_table :articles do |t|
t.column :status, :article_status
end
end
# NOTE: It's important to drop table before dropping enum.
def down
drop_table :articles
execute < < -SQL
DROP TYPE article_status;
SQL
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/article.rb
2015-12-12 08:25:00 -05:00
class Article < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Article.create status: "draft"
irb> article = Article.first
irb> article.status
=> "draft"
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> article.status = "published"
irb> article.save!
2014-01-21 06:13:11 -05:00
```
2017-07-30 08:52:31 -04:00
To add a new value before/after existing one you should use [ALTER TYPE ](https://www.postgresql.org/docs/current/static/sql-altertype.html ):
2015-10-13 16:50:19 -04:00
2015-07-22 11:52:24 -04:00
```ruby
# db/migrate/20150720144913_add_new_state_to_articles.rb
# NOTE: ALTER TYPE ... ADD VALUE cannot be executed inside of a transaction block so here we are using disable_ddl_transaction!
disable_ddl_transaction!
def up
execute < < -SQL
ALTER TYPE article_status ADD VALUE IF NOT EXISTS 'archived' AFTER 'published';
SQL
end
```
2017-07-30 08:52:31 -04:00
NOTE: ENUM values can't be dropped currently. You can read why [here ](https://www.postgresql.org/message-id/29F36C7C98AB09499B1A209D48EAA615B7653DBC8A@mail2a.alliedtesting.com ).
2015-07-22 11:52:24 -04:00
2019-01-22 03:53:47 -05:00
Hint: to show all the values of the all enums you have, you should call this query in `bin/rails db` or `psql` console:
2015-10-13 16:50:19 -04:00
2015-07-22 11:52:24 -04:00
```sql
SELECT n.nspname AS enum_schema,
t.typname AS enum_name,
e.enumlabel AS enum_value
FROM pg_type t
JOIN pg_enum e ON t.oid = e.enumtypid
JOIN pg_catalog.pg_namespace n ON n.oid = t.typnamespace
```
2014-01-21 06:13:11 -05:00
### UUID
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-uuid.html )
2019-12-23 21:11:45 -05:00
* [pgcrypto generator function ](https://www.postgresql.org/docs/current/static/pgcrypto.html )
2017-07-30 08:52:31 -04:00
* [uuid-ossp generator functions ](https://www.postgresql.org/docs/current/static/uuid-ossp.html )
2014-01-21 06:13:11 -05:00
2015-10-13 16:50:19 -04:00
NOTE: You need to enable the `pgcrypto` (only PostgreSQL >= 9.4) or `uuid-ossp`
2015-04-22 23:39:07 -04:00
extension to use uuid.
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20131220144913_create_revisions.rb
create_table :revisions do |t|
2015-08-08 05:37:22 -04:00
t.uuid :identifier
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-01-21 06:13:11 -05:00
# app/models/revision.rb
2015-12-12 08:25:00 -05:00
class Revision < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Revision.create identifier: "A0EEBC99-9C0B-4EF8-BB6D-6BB9BD380A11"
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
irb> revision = Revision.first
irb> revision.identifier
=> "a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11"
2014-01-21 06:13:11 -05:00
```
2015-06-15 05:31:54 -04:00
You can use `uuid` type to define references in migrations:
2015-04-18 00:44:00 -04:00
```ruby
# db/migrate/20150418012400_create_blog.rb
2015-06-15 05:31:54 -04:00
enable_extension 'pgcrypto' unless extension_enabled?('pgcrypto')
2020-08-08 05:41:34 -04:00
create_table :posts, id: :uuid
2015-04-18 00:44:00 -04:00
2020-08-08 05:41:34 -04:00
create_table :comments, id: :uuid do |t|
2015-04-18 00:44:00 -04:00
# t.belongs_to :post, type: :uuid
t.references :post, type: :uuid
end
2020-12-23 17:29:10 -05:00
```
2015-04-18 00:44:00 -04:00
2020-12-23 17:29:10 -05:00
```ruby
2015-04-18 00:44:00 -04:00
# app/models/post.rb
2015-12-12 08:25:00 -05:00
class Post < ApplicationRecord
2015-04-18 00:44:00 -04:00
has_many :comments
end
2020-12-23 17:29:10 -05:00
```
2015-04-18 00:44:00 -04:00
2020-12-23 17:29:10 -05:00
```ruby
2015-04-18 00:44:00 -04:00
# app/models/comment.rb
2015-12-12 08:25:00 -05:00
class Comment < ApplicationRecord
2015-04-18 00:44:00 -04:00
belongs_to :post
end
```
2015-06-15 05:31:54 -04:00
See [this section ](#uuid-primary-keys ) for more details on using UUIDs as primary key.
2014-01-21 06:13:11 -05:00
### Bit String Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-bit.html )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-bitstring.html )
2014-01-21 06:13:11 -05:00
```ruby
# db/migrate/20131220144913_create_users.rb
create_table :users, force: true do |t|
t.column :settings, "bit(8)"
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2018-05-06 03:43:05 -04:00
# app/models/user.rb
2015-12-12 08:25:00 -05:00
class User < ApplicationRecord
2014-01-21 06:13:11 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-01-21 06:13:11 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> User.create settings: "01010011"
irb> user = User.first
irb> user.settings
=> "01010011"
irb> user.settings = "0xAF"
irb> user.settings
=> 10101111
irb> user.save!
2014-01-21 06:13:11 -05:00
```
### Network Address Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-net-types.html )
2014-01-21 06:13:11 -05:00
2014-05-18 12:58:50 -04:00
The types `inet` and `cidr` are mapped to Ruby
2021-02-04 11:34:53 -05:00
[`IPAddr` ](https://ruby-doc.org/stdlib-2.7.0/libdoc/ipaddr/rdoc/IPAddr.html )
2014-05-18 12:58:50 -04:00
objects. The `macaddr` type is mapped to normal text.
2014-01-21 06:13:11 -05:00
2014-05-08 05:27:35 -04:00
```ruby
# db/migrate/20140508144913_create_devices.rb
create_table(:devices, force: true) do |t|
t.inet 'ip'
t.cidr 'network'
t.macaddr 'address'
end
2020-10-31 17:44:05 -04:00
```
2014-05-08 05:27:35 -04:00
2020-10-31 17:44:05 -04:00
```ruby
2014-05-08 05:27:35 -04:00
# app/models/device.rb
2015-12-12 08:25:00 -05:00
class Device < ApplicationRecord
2014-05-08 05:27:35 -04:00
end
2020-10-31 17:44:05 -04:00
```
2014-05-08 05:27:35 -04:00
2020-10-31 17:44:05 -04:00
```irb
irb> macbook = Device.create(ip: "192.168.1.12", network: "192.168.2.0/24", address: "32:01:16:6d:05:ef")
2014-05-08 05:27:35 -04:00
2020-10-31 17:44:05 -04:00
irb> macbook.ip
=> #< IPAddr: IPv4:192 . 168 . 1 . 12 / 255 . 255 . 255 . 255 >
2014-05-08 05:27:35 -04:00
2020-10-31 17:44:05 -04:00
irb> macbook.network
=> #< IPAddr: IPv4:192 . 168 . 2 . 0 / 255 . 255 . 255 . 0 >
2014-05-08 05:27:35 -04:00
2020-10-31 17:44:05 -04:00
irb> macbook.address
=> "32:01:16:6d:05:ef"
2014-05-08 05:27:35 -04:00
```
2014-01-21 06:13:11 -05:00
### Geometric Types
2017-07-30 08:52:31 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-geometric.html )
2014-01-21 06:13:11 -05:00
2014-06-06 10:50:10 -04:00
All geometric types, with the exception of `points` are mapped to normal text.
A point is casted to an array containing `x` and `y` coordinates.
2014-01-21 06:13:11 -05:00
2020-01-20 11:26:41 -05:00
### Interval
2021-04-11 18:25:38 -04:00
* [type definition ](https://www.postgresql.org/docs/current/static/datatype-datetime.html#DATATYPE-INTERVAL-INPUT )
* [functions and operators ](https://www.postgresql.org/docs/current/static/functions-datetime.html )
2020-01-20 11:26:41 -05:00
2021-04-11 18:25:38 -04:00
This type is mapped to [`ActiveSupport::Duration` ](https://api.rubyonrails.org/classes/ActiveSupport/Duration.html ) objects.
2020-01-20 11:26:41 -05:00
```ruby
# db/migrate/20200120000000_create_events.rb
create_table :events do |t|
t.interval 'duration'
end
2020-10-31 17:44:05 -04:00
```
2020-01-20 11:26:41 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2020-01-20 11:26:41 -05:00
# app/models/event.rb
class Event < ApplicationRecord
end
2020-10-31 17:44:05 -04:00
```
2020-01-20 11:26:41 -05:00
2020-10-31 17:44:05 -04:00
```irb
irb> Event.create(duration: 2.days)
2020-01-20 11:26:41 -05:00
2020-10-31 17:44:05 -04:00
irb> event = Event.first
irb> event.duration
=> 2 days
2020-01-20 11:26:41 -05:00
```
2014-02-24 13:25:15 -05:00
UUID Primary Keys
-----------------
2015-10-13 16:50:19 -04:00
NOTE: You need to enable the `pgcrypto` (only PostgreSQL >= 9.4) or `uuid-ossp`
2015-04-22 23:39:07 -04:00
extension to generate random UUIDs.
2014-02-24 13:25:15 -05:00
```ruby
# db/migrate/20131220144913_create_devices.rb
2015-04-22 23:39:07 -04:00
enable_extension 'pgcrypto' unless extension_enabled?('pgcrypto')
2020-08-08 05:41:34 -04:00
create_table :devices, id: :uuid do |t|
2014-02-24 13:25:15 -05:00
t.string :kind
end
2020-10-31 17:44:05 -04:00
```
2014-02-24 13:25:15 -05:00
2020-10-31 17:44:05 -04:00
```ruby
2014-02-24 13:25:15 -05:00
# app/models/device.rb
2015-12-12 08:25:00 -05:00
class Device < ApplicationRecord
2014-02-24 13:25:15 -05:00
end
2020-10-31 17:44:05 -04:00
```
2014-02-24 13:25:15 -05:00
2020-10-31 17:44:05 -04:00
```ruby
irb> device = Device.create
irb> device.id
=> "814865cd-5a1d-4771-9306-4268f188fe9e"
2014-02-24 13:25:15 -05:00
```
2016-11-24 04:42:45 -05:00
NOTE: `gen_random_uuid()` (from `pgcrypto` ) is assumed if no `:default` option was
2015-06-15 05:31:54 -04:00
passed to `create_table` .
2020-05-20 10:24:00 -04:00
Generated Columns
-----------------
NOTE: Generated columns are supported since version 12.0 of PostgreSQL.
```ruby
# db/migrate/20131220144913_create_users.rb
create_table :users do |t|
t.string :name
2021-04-06 13:04:50 -04:00
t.virtual :name_upcased, type: :string, as: 'upper(name)', stored: true
2020-05-20 10:24:00 -04:00
end
# app/models/user.rb
class User < ApplicationRecord
end
# Usage
user = User.create(name: 'John')
User.last.name_upcased # => "JOHN"
```
2014-02-24 13:25:15 -05:00
Full Text Search
----------------
```ruby
# db/migrate/20131220144913_create_documents.rb
create_table :documents do |t|
2020-05-20 10:24:00 -04:00
t.string :title
t.string :body
2014-02-24 13:25:15 -05:00
end
2016-05-28 01:26:04 -04:00
add_index :documents, "to_tsvector('english', title || ' ' || body)", using: :gin, name: 'documents_idx'
2020-12-23 17:29:10 -05:00
```
2014-02-24 13:25:15 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-02-24 13:25:15 -05:00
# app/models/document.rb
2015-12-12 08:25:00 -05:00
class Document < ApplicationRecord
2014-02-24 13:25:15 -05:00
end
2020-12-23 17:29:10 -05:00
```
2014-02-24 13:25:15 -05:00
2020-12-23 17:29:10 -05:00
```ruby
2014-02-24 13:25:15 -05:00
# Usage
Document.create(title: "Cats and Dogs", body: "are nice!")
## all documents matching 'cat & dog'
Document.where("to_tsvector('english', title || ' ' || body) @@ to_tsquery(?)",
"cat & dog")
```
2020-05-20 10:24:00 -04:00
Optionally, you can store the vector as automatically generated column (from PostgreSQL 12.0):
```ruby
# db/migrate/20131220144913_create_documents.rb
create_table :documents do |t|
t.string :title
t.string :body
t.virtual :textsearchable_index_col,
2021-09-16 11:22:26 -04:00
type: :tsvector, as: "to_tsvector('english', title || ' ' || body)", stored: true
2020-05-20 10:24:00 -04:00
end
add_index :documents, :textsearchable_index_col, using: :gin, name: 'documents_idx'
# Usage
Document.create(title: "Cats and Dogs", body: "are nice!")
## all documents matching 'cat & dog'
Document.where("textsearchable_index_col @@ to_tsquery(?)", "cat & dog")
```
2014-06-14 05:20:58 -04:00
Database Views
--------------
2014-05-11 07:47:30 -04:00
2017-07-30 08:52:31 -04:00
* [view creation ](https://www.postgresql.org/docs/current/static/sql-createview.html )
2014-05-11 07:47:30 -04:00
Imagine you need to work with a legacy database containing the following table:
```
rails_pg_guide=# \d "TBL_ART"
Table "public.TBL_ART"
Column | Type | Modifiers
------------+-----------------------------+------------------------------------------------------------
INT_ID | integer | not null default nextval('"TBL_ART_INT_ID_seq"'::regclass)
STR_TITLE | character varying |
STR_STAT | character varying | default 'draft'::character varying
DT_PUBL_AT | timestamp without time zone |
BL_ARCH | boolean | default false
Indexes:
"TBL_ART_pkey" PRIMARY KEY, btree ("INT_ID")
```
This table does not follow the Rails conventions at all.
Because simple PostgreSQL views are updateable by default,
we can wrap it as follows:
```ruby
# db/migrate/20131220144913_create_articles_view.rb
execute < < -SQL
CREATE VIEW articles AS
SELECT "INT_ID" AS id,
"STR_TITLE" AS title,
"STR_STAT" AS status,
"DT_PUBL_AT" AS published_at,
"BL_ARCH" AS archived
FROM "TBL_ART"
WHERE "BL_ARCH" = 'f'
SQL
2020-10-31 17:44:05 -04:00
```
2014-05-11 07:47:30 -04:00
2020-10-31 17:44:05 -04:00
```ruby
2014-05-11 07:47:30 -04:00
# app/models/article.rb
2015-12-12 08:25:00 -05:00
class Article < ApplicationRecord
2014-05-11 07:47:30 -04:00
self.primary_key = "id"
def archive!
update_attribute :archived, true
end
end
2020-10-31 17:44:05 -04:00
```
2014-05-11 07:47:30 -04:00
2020-10-31 17:44:05 -04:00
```irb
irb> first = Article.create! title: "Winter is coming", status: "published", published_at: 1.year.ago
irb> second = Article.create! title: "Brace yourself", status: "draft", published_at: 1.month.ago
irb> Article.count
=> 2
irb> first.archive!
irb> Article.count
=> 1
2014-05-11 07:47:30 -04:00
```
2014-05-29 05:23:59 -04:00
NOTE: This application only cares about non-archived `Articles` . A view also
2014-05-11 07:47:30 -04:00
allows for conditions so we can exclude the archived `Articles` directly.