active_record_postgresql.md 13.4 KB
Newer Older
1
**DO NOT READ THIS FILE ON GITHUB, GUIDES ARE PUBLISHED ON http://guides.rubyonrails.org.**
X
Xavier Noria 已提交
2

3
Active Record and PostgreSQL
4 5
============================

6
This guide covers PostgreSQL specific usage of Active Record.
7

8 9 10
After reading this guide, you will know:

* How to use PostgreSQL's datatypes.
11 12
* How to use UUID primary keys.
* How to implement full text search with PostgreSQL.
13
* How to back your Active Record models with database views.
14 15 16

--------------------------------------------------------------------------------

17
In order to use the PostgreSQL adapter you need to have at least version 9.1
18 19 20 21 22 23
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).
It describes how to properly setup Active Record for PostgreSQL.

24 25 26 27 28 29 30 31
Datatypes
---------

PostgreSQL offers a number of specific datatypes. Following is a list of types,
that are supported by the PostgreSQL adapter.

### Bytea

32 33
* [type definition](http://www.postgresql.org/docs/current/static/datatype-binary.html)
* [functions and operators](http://www.postgresql.org/docs/current/static/functions-binarystring.html)
34 35 36 37 38 39 40 41

```ruby
# db/migrate/20140207133952_create_documents.rb
create_table :documents do |t|
  t.binary 'payload'
end

# app/models/document.rb
42
class Document < ApplicationRecord
43 44 45 46 47 48 49 50 51
end

# Usage
data = File.read(Rails.root + "tmp/output.pdf")
Document.create payload: data
```

### Array

52 53
* [type definition](http://www.postgresql.org/docs/current/static/arrays.html)
* [functions and operators](http://www.postgresql.org/docs/current/static/functions-array.html)
54 55 56

```ruby
# db/migrate/20140207133952_create_books.rb
57
create_table :books do |t|
58 59 60 61
  t.string 'title'
  t.string 'tags', array: true
  t.integer 'ratings', array: true
end
62 63
add_index :books, :tags, using: 'gin'
add_index :books, :ratings, using: 'gin'
64 65

# app/models/book.rb
66
class Book < ApplicationRecord
67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85
end

# 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

86
* [type definition](http://www.postgresql.org/docs/current/static/hstore.html)
87
* [functions and operators](http://www.postgresql.org/docs/current/static/hstore.html#AEN167712)
88

89
NOTE: You need to enable the `hstore` extension to use hstore.
90

91 92 93
```ruby
# db/migrate/20131009135255_create_profiles.rb
ActiveRecord::Schema.define do
94
  enable_extension 'hstore' unless extension_enabled?('hstore')
95 96 97 98 99 100
  create_table :profiles do |t|
    t.hstore 'settings'
  end
end

# app/models/profile.rb
101
class Profile < ApplicationRecord
102 103 104 105 106 107 108 109
end

# Usage
Profile.create(settings: { "color" => "blue", "resolution" => "800x600" })

profile = Profile.first
profile.settings # => {"color"=>"blue", "resolution"=>"800x600"}

110
profile.settings = {"color" => "yellow", "resolution" => "1280x1024"}
111
profile.save!
112 113 114

Profile.where("settings->'color' = ?", "yellow")
#=> #<ActiveRecord::Relation [#<Profile id: 1, settings: {"color"=>"yellow", "resolution"=>"1280x1024"}>]>
115 116
```

117
### JSON
118

119 120
* [type definition](http://www.postgresql.org/docs/current/static/datatype-json.html)
* [functions and operators](http://www.postgresql.org/docs/current/static/functions-json.html)
121 122 123 124 125 126 127 128

```ruby
# db/migrate/20131220144913_create_events.rb
create_table :events do |t|
  t.json 'payload'
end

# app/models/event.rb
129
class Event < ApplicationRecord
130 131 132 133 134 135 136 137 138
end

# Usage
Event.create(payload: { kind: "user_renamed", change: ["jack", "john"]})

event = Event.first
event.payload # => {"kind"=>"user_renamed", "change"=>["jack", "john"]}

## Query based on JSON document
139 140
# The -> operator returns the original JSON type (which might be an object), whereas ->> returns text
Event.where("payload->>'kind' = ?", "user_renamed")
141 142 143 144
```

### Range Types

145 146
* [type definition](http://www.postgresql.org/docs/current/static/rangetypes.html)
* [functions and operators](http://www.postgresql.org/docs/current/static/functions-range.html)
147

148
This type is mapped to Ruby [`Range`](http://www.ruby-doc.org/core-2.2.2/Range.html) objects.
149 150 151 152 153 154 155 156

```ruby
# db/migrate/20130923065404_create_events.rb
create_table :events do |t|
  t.daterange 'duration'
end

# app/models/event.rb
157
class Event < ApplicationRecord
158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179
end

# Usage
Event.create(duration: Date.new(2014, 2, 11)..Date.new(2014, 2, 12))

event = Event.first
event.duration # => Tue, 11 Feb 2014...Thu, 13 Feb 2014

## All Events on a given date
Event.where("duration @> ?::date", Date.new(2014, 2, 12))

## Working with range bounds
event = Event.
  select("lower(duration) AS starts_at").
  select("upper(duration) AS ends_at").first

event.starts_at # => Tue, 11 Feb 2014
event.ends_at # => Thu, 13 Feb 2014
```

### Composite Types

180
* [type definition](http://www.postgresql.org/docs/current/static/rowtypes.html)
181

182
Currently there is no special support for composite types. They are mapped to
183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206
normal text columns:

```sql
CREATE TYPE full_address AS
(
  city VARCHAR(90),
  street VARCHAR(90)
);
```

```ruby
# db/migrate/20140207133952_create_contacts.rb
execute <<-SQL
 CREATE TYPE full_address AS
 (
   city VARCHAR(90),
   street VARCHAR(90)
 );
SQL
create_table :contacts do |t|
  t.column :address, :full_address
end

# app/models/contact.rb
207
class Contact < ApplicationRecord
208 209 210 211 212 213 214 215 216 217 218 219
end

# Usage
Contact.create address: "(Paris,Champs-Élysées)"
contact = Contact.first
contact.address # => "(Paris,Champs-Élysées)"
contact.address = "(Paris,Rue Basse)"
contact.save!
```

### Enumerated Types

220
* [type definition](http://www.postgresql.org/docs/current/static/datatype-enum.html)
221 222 223 224 225

Currently there is no special support for enumerated types. They are mapped as
normal text columns:

```ruby
226
# db/migrate/20131220144913_create_articles.rb
227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242
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
243 244 245
end

# app/models/article.rb
246
class Article < ApplicationRecord
247 248 249 250 251 252 253 254 255 256 257
end

# Usage
Article.create status: "draft"
article = Article.first
article.status # => "draft"

article.status = "published"
article.save!
```

258
To add a new value before/after existing one you should use [ALTER TYPE](http://www.postgresql.org/docs/current/static/sql-altertype.html):
259

260 261 262 263 264 265 266 267 268 269 270 271
```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
```

272
NOTE: ENUM values can't be dropped currently. You can read why [here](http://www.postgresql.org/message-id/29F36C7C98AB09499B1A209D48EAA615B7653DBC8A@mail2a.alliedtesting.com).
273 274

Hint: to show all the values of the all enums you have, you should call this query in `bin/rails db` or `psql` console:
275

276 277 278 279 280 281 282 283 284
```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
```

285 286
### UUID

287 288 289
* [type definition](http://www.postgresql.org/docs/current/static/datatype-uuid.html)
* [pgcrypto generator function](http://www.postgresql.org/docs/current/static/pgcrypto.html#AEN159361)
* [uuid-ossp generator functions](http://www.postgresql.org/docs/current/static/uuid-ossp.html)
290

291
NOTE: You need to enable the `pgcrypto` (only PostgreSQL >= 9.4) or `uuid-ossp`
292
extension to use uuid.
293 294 295 296

```ruby
# db/migrate/20131220144913_create_revisions.rb
create_table :revisions do |t|
297
  t.uuid :identifier
298 299 300
end

# app/models/revision.rb
301
class Revision < ApplicationRecord
302 303 304 305 306 307 308 309 310
end

# Usage
Revision.create identifier: "A0EEBC99-9C0B-4EF8-BB6D-6BB9BD380A11"

revision = Revision.first
revision.identifier # => "a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11"
```

311
You can use `uuid` type to define references in migrations:
312 313 314

```ruby
# db/migrate/20150418012400_create_blog.rb
315 316
enable_extension 'pgcrypto' unless extension_enabled?('pgcrypto')
create_table :posts, id: :uuid, default: 'gen_random_uuid()'
317

318
create_table :comments, id: :uuid, default: 'gen_random_uuid()' do |t|
319 320 321 322 323
  # t.belongs_to :post, type: :uuid
  t.references :post, type: :uuid
end

# app/models/post.rb
324
class Post < ApplicationRecord
325 326 327 328
  has_many :comments
end

# app/models/comment.rb
329
class Comment < ApplicationRecord
330 331 332 333
  belongs_to :post
end
```

334 335
See [this section](#uuid-primary-keys) for more details on using UUIDs as primary key.

336 337
### Bit String Types

338 339
* [type definition](http://www.postgresql.org/docs/current/static/datatype-bit.html)
* [functions and operators](http://www.postgresql.org/docs/current/static/functions-bitstring.html)
340 341 342 343 344 345 346 347

```ruby
# db/migrate/20131220144913_create_users.rb
create_table :users, force: true do |t|
  t.column :settings, "bit(8)"
end

# app/models/device.rb
348
class User < ApplicationRecord
349 350 351 352 353
end

# Usage
User.create settings: "01010011"
user = User.first
354
user.settings # => "01010011"
355 356 357 358 359 360 361
user.settings = "0xAF"
user.settings # => 10101111
user.save!
```

### Network Address Types

362
* [type definition](http://www.postgresql.org/docs/current/static/datatype-net-types.html)
363

364
The types `inet` and `cidr` are mapped to Ruby
365
[`IPAddr`](http://www.ruby-doc.org/stdlib-2.2.2/libdoc/ipaddr/rdoc/IPAddr.html)
366
objects. The `macaddr` type is mapped to normal text.
367

368 369 370 371 372 373 374 375 376
```ruby
# db/migrate/20140508144913_create_devices.rb
create_table(:devices, force: true) do |t|
  t.inet 'ip'
  t.cidr 'network'
  t.macaddr 'address'
end

# app/models/device.rb
377
class Device < ApplicationRecord
378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394
end

# Usage
macbook = Device.create(ip: "192.168.1.12",
                        network: "192.168.2.0/24",
                        address: "32:01:16:6d:05:ef")

macbook.ip
# => #<IPAddr: IPv4:192.168.1.12/255.255.255.255>

macbook.network
# => #<IPAddr: IPv4:192.168.2.0/255.255.255.0>

macbook.address
# => "32:01:16:6d:05:ef"
```

395 396
### Geometric Types

397
* [type definition](http://www.postgresql.org/docs/current/static/datatype-geometric.html)
398

Y
Yves Senn 已提交
399 400
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.
401

402 403 404 405

UUID Primary Keys
-----------------

406
NOTE: You need to enable the `pgcrypto` (only PostgreSQL >= 9.4) or `uuid-ossp`
407
extension to generate random UUIDs.
408 409 410

```ruby
# db/migrate/20131220144913_create_devices.rb
411 412
enable_extension 'pgcrypto' unless extension_enabled?('pgcrypto')
create_table :devices, id: :uuid, default: 'gen_random_uuid()' do |t|
413 414 415 416
  t.string :kind
end

# app/models/device.rb
417
class Device < ApplicationRecord
418 419 420 421 422 423 424
end

# Usage
device = Device.create
device.id # => "814865cd-5a1d-4771-9306-4268f188fe9e"
```

425 426 427
NOTE: `uuid_generate_v4()` (from `uuid-ossp`) is assumed if no `:default` option was
passed to `create_table`.

428 429 430 431 432 433 434 435 436 437
Full Text Search
----------------

```ruby
# db/migrate/20131220144913_create_documents.rb
create_table :documents do |t|
  t.string 'title'
  t.string 'body'
end

438
add_index :documents, "to_tsvector('english', title || ' ' || body)", using: :gin, name: 'documents_idx'
439 440

# app/models/document.rb
441
class Document < ApplicationRecord
442 443 444 445 446 447 448 449 450 451
end

# 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")
```

452 453
Database Views
--------------
454

455
* [view creation](http://www.postgresql.org/docs/current/static/sql-createview.html)
456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490

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

# app/models/article.rb
491
class Article < ApplicationRecord
492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507
  self.primary_key = "id"
  def archive!
    update_attribute :archived, true
  end
end

# Usage
first = Article.create! title: "Winter is coming",
                        status: "published",
                        published_at: 1.year.ago
second = Article.create! title: "Brace yourself",
                         status: "draft",
                         published_at: 1.month.ago

Article.count # => 1
first.archive!
Y
Yves Senn 已提交
508
Article.count # => 2
509 510
```

511
NOTE: This application only cares about non-archived `Articles`. A view also
512
allows for conditions so we can exclude the archived `Articles` directly.