1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
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
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
|
'\" t
.\" Title: CREATE INDEX
.\" Author: The PostgreSQL Global Development Group
.\" Generator: DocBook XSL Stylesheets v1.79.1 <http://docbook.sf.net/>
.\" Date: 2021
.\" Manual: PostgreSQL 13.4 Documentation
.\" Source: PostgreSQL 13.4
.\" Language: English
.\"
.TH "CREATE INDEX" "7" "2021" "PostgreSQL 13.4" "PostgreSQL 13.4 Documentation"
.\" -----------------------------------------------------------------
.\" * Define some portability stuff
.\" -----------------------------------------------------------------
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.\" http://bugs.debian.org/507673
.\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
.\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
.ie \n(.g .ds Aq \(aq
.el .ds Aq '
.\" -----------------------------------------------------------------
.\" * set default formatting
.\" -----------------------------------------------------------------
.\" disable hyphenation
.nh
.\" disable justification (adjust text to left margin only)
.ad l
.\" -----------------------------------------------------------------
.\" * MAIN CONTENT STARTS HERE *
.\" -----------------------------------------------------------------
.SH "NAME"
CREATE_INDEX \- define a new index
.SH "SYNOPSIS"
.sp
.nf
CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] \fIname\fR ] ON [ ONLY ] \fItable_name\fR [ USING \fImethod\fR ]
( { \fIcolumn_name\fR | ( \fIexpression\fR ) } [ COLLATE \fIcollation\fR ] [ \fIopclass\fR [ ( \fIopclass_parameter\fR = \fIvalue\fR [, \&.\&.\&. ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, \&.\&.\&.] )
[ INCLUDE ( \fIcolumn_name\fR [, \&.\&.\&.] ) ]
[ WITH ( \fIstorage_parameter\fR [= \fIvalue\fR] [, \&.\&.\&. ] ) ]
[ TABLESPACE \fItablespace_name\fR ]
[ WHERE \fIpredicate\fR ]
.fi
.SH "DESCRIPTION"
.PP
\fBCREATE INDEX\fR
constructs an index on the specified column(s) of the specified relation, which can be a table or a materialized view\&. Indexes are primarily used to enhance database performance (though inappropriate use can result in slower performance)\&.
.PP
The key field(s) for the index are specified as column names, or alternatively as expressions written in parentheses\&. Multiple fields can be specified if the index method supports multicolumn indexes\&.
.PP
An index field can be an expression computed from the values of one or more columns of the table row\&. This feature can be used to obtain fast access to data based on some transformation of the basic data\&. For example, an index computed on
upper(col)
would allow the clause
WHERE upper(col) = \*(AqJIM\*(Aq
to use an index\&.
.PP
PostgreSQL
provides the index methods B\-tree, hash, GiST, SP\-GiST, GIN, and BRIN\&. Users can also define their own index methods, but that is fairly complicated\&.
.PP
When the
WHERE
clause is present, a
partial index
is created\&. A partial index is an index that contains entries for only a portion of a table, usually a portion that is more useful for indexing than the rest of the table\&. For example, if you have a table that contains both billed and unbilled orders where the unbilled orders take up a small fraction of the total table and yet that is an often used section, you can improve performance by creating an index on just that portion\&. Another possible application is to use
WHERE
with
UNIQUE
to enforce uniqueness over a subset of a table\&. See
Section\ \&11.8
for more discussion\&.
.PP
The expression used in the
WHERE
clause can refer only to columns of the underlying table, but it can use all columns, not just the ones being indexed\&. Presently, subqueries and aggregate expressions are also forbidden in
WHERE\&. The same restrictions apply to index fields that are expressions\&.
.PP
All functions and operators used in an index definition must be
\(lqimmutable\(rq, that is, their results must depend only on their arguments and never on any outside influence (such as the contents of another table or the current time)\&. This restriction ensures that the behavior of the index is well\-defined\&. To use a user\-defined function in an index expression or
WHERE
clause, remember to mark the function immutable when you create it\&.
.SH "PARAMETERS"
.PP
UNIQUE
.RS 4
Causes the system to check for duplicate values in the table when the index is created (if data already exist) and each time data is added\&. Attempts to insert or update data which would result in duplicate entries will generate an error\&.
.sp
Additional restrictions apply when unique indexes are applied to partitioned tables; see
CREATE TABLE (\fBCREATE_TABLE\fR(7))\&.
.RE
.PP
CONCURRENTLY
.RS 4
When this option is used,
PostgreSQL
will build the index without taking any locks that prevent concurrent inserts, updates, or deletes on the table; whereas a standard index build locks out writes (but not reads) on the table until it\*(Aqs done\&. There are several caveats to be aware of when using this option \(em see
Building Indexes Concurrently
below\&.
.sp
For temporary tables,
\fBCREATE INDEX\fR
is always non\-concurrent, as no other session can access them, and non\-concurrent index creation is cheaper\&.
.RE
.PP
IF NOT EXISTS
.RS 4
Do not throw an error if a relation with the same name already exists\&. A notice is issued in this case\&. Note that there is no guarantee that the existing index is anything like the one that would have been created\&. Index name is required when
IF NOT EXISTS
is specified\&.
.RE
.PP
INCLUDE
.RS 4
The optional
INCLUDE
clause specifies a list of columns which will be included in the index as
non\-key
columns\&. A non\-key column cannot be used in an index scan search qualification, and it is disregarded for purposes of any uniqueness or exclusion constraint enforced by the index\&. However, an index\-only scan can return the contents of non\-key columns without having to visit the index\*(Aqs table, since they are available directly from the index entry\&. Thus, addition of non\-key columns allows index\-only scans to be used for queries that otherwise could not use them\&.
.sp
It\*(Aqs wise to be conservative about adding non\-key columns to an index, especially wide columns\&. If an index tuple exceeds the maximum size allowed for the index type, data insertion will fail\&. In any case, non\-key columns duplicate data from the index\*(Aqs table and bloat the size of the index, thus potentially slowing searches\&. Furthermore, B\-tree deduplication is never used with indexes that have a non\-key column\&.
.sp
Columns listed in the
INCLUDE
clause don\*(Aqt need appropriate operator classes; the clause can include columns whose data types don\*(Aqt have operator classes defined for a given access method\&.
.sp
Expressions are not supported as included columns since they cannot be used in index\-only scans\&.
.sp
Currently, the B\-tree and the GiST index access methods support this feature\&. In B\-tree and the GiST indexes, the values of columns listed in the
INCLUDE
clause are included in leaf tuples which correspond to heap tuples, but are not included in upper\-level index entries used for tree navigation\&.
.RE
.PP
\fIname\fR
.RS 4
The name of the index to be created\&. No schema name can be included here; the index is always created in the same schema as its parent table\&. If the name is omitted,
PostgreSQL
chooses a suitable name based on the parent table\*(Aqs name and the indexed column name(s)\&.
.RE
.PP
ONLY
.RS 4
Indicates not to recurse creating indexes on partitions, if the table is partitioned\&. The default is to recurse\&.
.RE
.PP
\fItable_name\fR
.RS 4
The name (possibly schema\-qualified) of the table to be indexed\&.
.RE
.PP
\fImethod\fR
.RS 4
The name of the index method to be used\&. Choices are
btree,
hash,
gist,
spgist,
gin, and
brin\&. The default method is
btree\&.
.RE
.PP
\fIcolumn_name\fR
.RS 4
The name of a column of the table\&.
.RE
.PP
\fIexpression\fR
.RS 4
An expression based on one or more columns of the table\&. The expression usually must be written with surrounding parentheses, as shown in the syntax\&. However, the parentheses can be omitted if the expression has the form of a function call\&.
.RE
.PP
\fIcollation\fR
.RS 4
The name of the collation to use for the index\&. By default, the index uses the collation declared for the column to be indexed or the result collation of the expression to be indexed\&. Indexes with non\-default collations can be useful for queries that involve expressions using non\-default collations\&.
.RE
.PP
\fIopclass\fR
.RS 4
The name of an operator class\&. See below for details\&.
.RE
.PP
\fIopclass_parameter\fR
.RS 4
The name of an operator class parameter\&. See below for details\&.
.RE
.PP
ASC
.RS 4
Specifies ascending sort order (which is the default)\&.
.RE
.PP
DESC
.RS 4
Specifies descending sort order\&.
.RE
.PP
NULLS FIRST
.RS 4
Specifies that nulls sort before non\-nulls\&. This is the default when
DESC
is specified\&.
.RE
.PP
NULLS LAST
.RS 4
Specifies that nulls sort after non\-nulls\&. This is the default when
DESC
is not specified\&.
.RE
.PP
\fIstorage_parameter\fR
.RS 4
The name of an index\-method\-specific storage parameter\&. See
Index Storage Parameters
below for details\&.
.RE
.PP
\fItablespace_name\fR
.RS 4
The tablespace in which to create the index\&. If not specified,
default_tablespace
is consulted, or
temp_tablespaces
for indexes on temporary tables\&.
.RE
.PP
\fIpredicate\fR
.RS 4
The constraint expression for a partial index\&.
.RE
.SS "Index Storage Parameters"
.PP
The optional
WITH
clause specifies
storage parameters
for the index\&. Each index method has its own set of allowed storage parameters\&. The B\-tree, hash, GiST and SP\-GiST index methods all accept this parameter:
.PP
fillfactor (integer)
.RS 4
The fillfactor for an index is a percentage that determines how full the index method will try to pack index pages\&. For B\-trees, leaf pages are filled to this percentage during initial index build, and also when extending the index at the right (adding new largest key values)\&. If pages subsequently become completely full, they will be split, leading to gradual degradation in the index\*(Aqs efficiency\&. B\-trees use a default fillfactor of 90, but any integer value from 10 to 100 can be selected\&. If the table is static then fillfactor 100 is best to minimize the index\*(Aqs physical size, but for heavily updated tables a smaller fillfactor is better to minimize the need for page splits\&. The other index methods use fillfactor in different but roughly analogous ways; the default fillfactor varies between methods\&.
.RE
.PP
B\-tree indexes additionally accept this parameter:
.PP
deduplicate_items (boolean)
.RS 4
Controls usage of the B\-tree deduplication technique described in
Section\ \&63.4.2\&. Set to
ON
or
OFF
to enable or disable the optimization\&. (Alternative spellings of
ON
and
OFF
are allowed as described in
Section\ \&19.1\&.) The default is
ON\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
Turning
deduplicate_items
off via
\fBALTER INDEX\fR
prevents future insertions from triggering deduplication, but does not in itself make existing posting list tuples use the standard tuple representation\&.
.sp .5v
.RE
.RE
.PP
GiST indexes additionally accept this parameter:
.PP
buffering (enum)
.RS 4
Determines whether the buffering build technique described in
Section\ \&64.4.1
is used to build the index\&. With
OFF
it is disabled, with
ON
it is enabled, and with
AUTO
it is initially disabled, but turned on on\-the\-fly once the index size reaches
effective_cache_size\&. The default is
AUTO\&.
.RE
.PP
GIN indexes accept different parameters:
.PP
fastupdate (boolean)
.RS 4
This setting controls usage of the fast update technique described in
Section\ \&66.4.1\&. It is a Boolean parameter:
ON
enables fast update,
OFF
disables it\&. The default is
ON\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBNote\fR
.ps -1
.br
Turning
fastupdate
off via
\fBALTER INDEX\fR
prevents future insertions from going into the list of pending index entries, but does not in itself flush previous entries\&. You might want to
\fBVACUUM\fR
the table or call
\fBgin_clean_pending_list\fR
function afterward to ensure the pending list is emptied\&.
.sp .5v
.RE
.RE
.PP
gin_pending_list_limit (integer)
.RS 4
Custom
gin_pending_list_limit
parameter\&. This value is specified in kilobytes\&.
.RE
.PP
BRIN
indexes accept different parameters:
.PP
pages_per_range (integer)
.RS 4
Defines the number of table blocks that make up one block range for each entry of a
BRIN
index (see
Section\ \&67.1
for more details)\&. The default is
128\&.
.RE
.PP
autosummarize (boolean)
.RS 4
Defines whether a summarization run is invoked for the previous page range whenever an insertion is detected on the next one\&.
.RE
.SS "Building Indexes Concurrently"
.PP
Creating an index can interfere with regular operation of a database\&. Normally
PostgreSQL
locks the table to be indexed against writes and performs the entire index build with a single scan of the table\&. Other transactions can still read the table, but if they try to insert, update, or delete rows in the table they will block until the index build is finished\&. This could have a severe effect if the system is a live production database\&. Very large tables can take many hours to be indexed, and even for smaller tables, an index build can lock out writers for periods that are unacceptably long for a production system\&.
.PP
PostgreSQL
supports building indexes without locking out writes\&. This method is invoked by specifying the
CONCURRENTLY
option of
\fBCREATE INDEX\fR\&. When this option is used,
PostgreSQL
must perform two scans of the table, and in addition it must wait for all existing transactions that could potentially modify or use the index to terminate\&. Thus this method requires more total work than a standard index build and takes significantly longer to complete\&. However, since it allows normal operations to continue while the index is built, this method is useful for adding new indexes in a production environment\&. Of course, the extra CPU and I/O load imposed by the index creation might slow other operations\&.
.PP
In a concurrent index build, the index is actually entered into the system catalogs in one transaction, then two table scans occur in two more transactions\&. Before each table scan, the index build must wait for existing transactions that have modified the table to terminate\&. After the second scan, the index build must wait for any transactions that have a snapshot (see
Chapter\ \&13) predating the second scan to terminate, including transactions used by any phase of concurrent index builds on other tables\&. Then finally the index can be marked ready for use, and the
\fBCREATE INDEX\fR
command terminates\&. Even then, however, the index may not be immediately usable for queries: in the worst case, it cannot be used as long as transactions exist that predate the start of the index build\&.
.PP
If a problem arises while scanning the table, such as a deadlock or a uniqueness violation in a unique index, the
\fBCREATE INDEX\fR
command will fail but leave behind an
\(lqinvalid\(rq
index\&. This index will be ignored for querying purposes because it might be incomplete; however it will still consume update overhead\&. The
psql
\fB\ed\fR
command will report such an index as
INVALID:
.sp
.if n \{\
.RS 4
.\}
.nf
postgres=# \ed tab
Table "public\&.tab"
Column | Type | Collation | Nullable | Default
\-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-
col | integer | | |
Indexes:
"idx" btree (col) INVALID
.fi
.if n \{\
.RE
.\}
.sp
The recommended recovery method in such cases is to drop the index and try again to perform
\fBCREATE INDEX CONCURRENTLY\fR\&. (Another possibility is to rebuild the index with
\fBREINDEX INDEX CONCURRENTLY\fR)\&.
.PP
Another caveat when building a unique index concurrently is that the uniqueness constraint is already being enforced against other transactions when the second table scan begins\&. This means that constraint violations could be reported in other queries prior to the index becoming available for use, or even in cases where the index build eventually fails\&. Also, if a failure does occur in the second scan, the
\(lqinvalid\(rq
index continues to enforce its uniqueness constraint afterwards\&.
.PP
Concurrent builds of expression indexes and partial indexes are supported\&. Errors occurring in the evaluation of these expressions could cause behavior similar to that described above for unique constraint violations\&.
.PP
Regular index builds permit other regular index builds on the same table to occur simultaneously, but only one concurrent index build can occur on a table at a time\&. In either case, schema modification of the table is not allowed while the index is being built\&. Another difference is that a regular
\fBCREATE INDEX\fR
command can be performed within a transaction block, but
\fBCREATE INDEX CONCURRENTLY\fR
cannot\&.
.PP
Concurrent builds for indexes on partitioned tables are currently not supported\&. However, you may concurrently build the index on each partition individually and then finally create the partitioned index non\-concurrently in order to reduce the time where writes to the partitioned table will be locked out\&. In this case, building the partitioned index is a metadata only operation\&.
.SH "NOTES"
.PP
See
Chapter\ \&11
for information about when indexes can be used, when they are not used, and in which particular situations they can be useful\&.
.PP
Currently, only the B\-tree, GiST, GIN, and BRIN index methods support multicolumn indexes\&. Up to 32 fields can be specified by default\&. (This limit can be altered when building
PostgreSQL\&.) Only B\-tree currently supports unique indexes\&.
.PP
An
operator class
with optional parameters can be specified for each column of an index\&. The operator class identifies the operators to be used by the index for that column\&. For example, a B\-tree index on four\-byte integers would use the
int4_ops
class; this operator class includes comparison functions for four\-byte integers\&. In practice the default operator class for the column\*(Aqs data type is usually sufficient\&. The main point of having operator classes is that for some data types, there could be more than one meaningful ordering\&. For example, we might want to sort a complex\-number data type either by absolute value or by real part\&. We could do this by defining two operator classes for the data type and then selecting the proper class when creating an index\&. More information about operator classes is in
Section\ \&11.10
and in
Section\ \&37.16\&.
.PP
When
CREATE INDEX
is invoked on a partitioned table, the default behavior is to recurse to all partitions to ensure they all have matching indexes\&. Each partition is first checked to determine whether an equivalent index already exists, and if so, that index will become attached as a partition index to the index being created, which will become its parent index\&. If no matching index exists, a new index will be created and automatically attached; the name of the new index in each partition will be determined as if no index name had been specified in the command\&. If the
ONLY
option is specified, no recursion is done, and the index is marked invalid\&. (\fBALTER INDEX \&.\&.\&. ATTACH PARTITION\fR
marks the index valid, once all partitions acquire matching indexes\&.) Note, however, that any partition that is created in the future using
\fBCREATE TABLE \&.\&.\&. PARTITION OF\fR
will automatically have a matching index, regardless of whether
ONLY
is specified\&.
.PP
For index methods that support ordered scans (currently, only B\-tree), the optional clauses
ASC,
DESC,
NULLS FIRST, and/or
NULLS LAST
can be specified to modify the sort ordering of the index\&. Since an ordered index can be scanned either forward or backward, it is not normally useful to create a single\-column
DESC
index \(em that sort ordering is already available with a regular index\&. The value of these options is that multicolumn indexes can be created that match the sort ordering requested by a mixed\-ordering query, such as
SELECT \&.\&.\&. ORDER BY x ASC, y DESC\&. The
NULLS
options are useful if you need to support
\(lqnulls sort low\(rq
behavior, rather than the default
\(lqnulls sort high\(rq, in queries that depend on indexes to avoid sorting steps\&.
.PP
The system regularly collects statistics on all of a table\*(Aqs columns\&. Newly\-created non\-expression indexes can immediately use these statistics to determine an index\*(Aqs usefulness\&. For new expression indexes, it is necessary to run
\fBANALYZE\fR
or wait for the
autovacuum daemon
to analyze the table to generate statistics for these indexes\&.
.PP
For most index methods, the speed of creating an index is dependent on the setting of
maintenance_work_mem\&. Larger values will reduce the time needed for index creation, so long as you don\*(Aqt make it larger than the amount of memory really available, which would drive the machine into swapping\&.
.PP
PostgreSQL
can build indexes while leveraging multiple CPUs in order to process the table rows faster\&. This feature is known as
parallel index build\&. For index methods that support building indexes in parallel (currently, only B\-tree),
\fImaintenance_work_mem\fR
specifies the maximum amount of memory that can be used by each index build operation as a whole, regardless of how many worker processes were started\&. Generally, a cost model automatically determines how many worker processes should be requested, if any\&.
.PP
Parallel index builds may benefit from increasing
\fImaintenance_work_mem\fR
where an equivalent serial index build will see little or no benefit\&. Note that
\fImaintenance_work_mem\fR
may influence the number of worker processes requested, since parallel workers must have at least a
32MB
share of the total
\fImaintenance_work_mem\fR
budget\&. There must also be a remaining
32MB
share for the leader process\&. Increasing
max_parallel_maintenance_workers
may allow more workers to be used, which will reduce the time needed for index creation, so long as the index build is not already I/O bound\&. Of course, there should also be sufficient CPU capacity that would otherwise lie idle\&.
.PP
Setting a value for
parallel_workers
via
ALTER TABLE (\fBALTER_TABLE\fR(7))
directly controls how many parallel worker processes will be requested by a
\fBCREATE INDEX\fR
against the table\&. This bypasses the cost model completely, and prevents
\fImaintenance_work_mem\fR
from affecting how many parallel workers are requested\&. Setting
parallel_workers
to 0 via
\fBALTER TABLE\fR
will disable parallel index builds on the table in all cases\&.
.if n \{\
.sp
.\}
.RS 4
.it 1 an-trap
.nr an-no-space-flag 1
.nr an-break-flag 1
.br
.ps +1
\fBTip\fR
.ps -1
.br
.PP
You might want to reset
parallel_workers
after setting it as part of tuning an index build\&. This avoids inadvertent changes to query plans, since
parallel_workers
affects
\fIall\fR
parallel table scans\&.
.sp .5v
.RE
.PP
While
\fBCREATE INDEX\fR
with the
CONCURRENTLY
option supports parallel builds without special restrictions, only the first table scan is actually performed in parallel\&.
.PP
Use
DROP INDEX (\fBDROP_INDEX\fR(7))
to remove an index\&.
.PP
Like any long\-running transaction,
\fBCREATE INDEX\fR
on a table can affect which tuples can be removed by concurrent
\fBVACUUM\fR
on any other table\&.
.PP
Prior releases of
PostgreSQL
also had an R\-tree index method\&. This method has been removed because it had no significant advantages over the GiST method\&. If
USING rtree
is specified,
\fBCREATE INDEX\fR
will interpret it as
USING gist, to simplify conversion of old databases to GiST\&.
.SH "EXAMPLES"
.PP
To create a unique B\-tree index on the column
title
in the table
films:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE UNIQUE INDEX title_idx ON films (title);
.fi
.if n \{\
.RE
.\}
.PP
To create a unique B\-tree index on the column
title
with included columns
director
and
rating
in the table
films:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
.fi
.if n \{\
.RE
.\}
.PP
To create a B\-Tree index with deduplication disabled:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX title_idx ON films (title) WITH (deduplicate_items = off);
.fi
.if n \{\
.RE
.\}
.PP
To create an index on the expression
lower(title), allowing efficient case\-insensitive searches:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX ON films ((lower(title)));
.fi
.if n \{\
.RE
.\}
.sp
(In this example we have chosen to omit the index name, so the system will choose a name, typically
films_lower_idx\&.)
.PP
To create an index with non\-default collation:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
.fi
.if n \{\
.RE
.\}
.PP
To create an index with non\-default sort ordering of nulls:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
.fi
.if n \{\
.RE
.\}
.PP
To create an index with non\-default fill factor:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
.fi
.if n \{\
.RE
.\}
.PP
To create a
GIN
index with fast updates disabled:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
.fi
.if n \{\
.RE
.\}
.PP
To create an index on the column
code
in the table
films
and have the index reside in the tablespace
indexspace:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
.fi
.if n \{\
.RE
.\}
.PP
To create a GiST index on a point attribute so that we can efficiently use box operators on the result of the conversion function:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX pointloc
ON points USING gist (box(location,location));
SELECT * FROM points
WHERE box(location,location) && \*(Aq(0,0),(1,1)\*(Aq::box;
.fi
.if n \{\
.RE
.\}
.PP
To create an index without locking out writes to the table:
.sp
.if n \{\
.RS 4
.\}
.nf
CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
.fi
.if n \{\
.RE
.\}
.SH "COMPATIBILITY"
.PP
\fBCREATE INDEX\fR
is a
PostgreSQL
language extension\&. There are no provisions for indexes in the SQL standard\&.
.SH "SEE ALSO"
ALTER INDEX (\fBALTER_INDEX\fR(7)), DROP INDEX (\fBDROP_INDEX\fR(7)), \fBREINDEX\fR(7)
|