1CREATE INDEX(7) PostgreSQL 14.3 Documentation CREATE INDEX(7)
2
3
4
6 CREATE_INDEX - define a new index
7
9 CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] name ] ON [ ONLY ] table_name [ USING method ]
10 ( { column_name | ( expression ) } [ COLLATE collation ] [ opclass [ ( opclass_parameter = value [, ... ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
11 [ INCLUDE ( column_name [, ...] ) ]
12 [ WITH ( storage_parameter [= value] [, ... ] ) ]
13 [ TABLESPACE tablespace_name ]
14 [ WHERE predicate ]
15
17 CREATE INDEX constructs an index on the specified column(s) of the
18 specified relation, which can be a table or a materialized view.
19 Indexes are primarily used to enhance database performance (though
20 inappropriate use can result in slower performance).
21
22 The key field(s) for the index are specified as column names, or
23 alternatively as expressions written in parentheses. Multiple fields
24 can be specified if the index method supports multicolumn indexes.
25
26 An index field can be an expression computed from the values of one or
27 more columns of the table row. This feature can be used to obtain fast
28 access to data based on some transformation of the basic data. For
29 example, an index computed on upper(col) would allow the clause WHERE
30 upper(col) = 'JIM' to use an index.
31
32 PostgreSQL provides the index methods B-tree, hash, GiST, SP-GiST, GIN,
33 and BRIN. Users can also define their own index methods, but that is
34 fairly complicated.
35
36 When the WHERE clause is present, a partial index is created. A partial
37 index is an index that contains entries for only a portion of a table,
38 usually a portion that is more useful for indexing than the rest of the
39 table. For example, if you have a table that contains both billed and
40 unbilled orders where the unbilled orders take up a small fraction of
41 the total table and yet that is an often used section, you can improve
42 performance by creating an index on just that portion. Another possible
43 application is to use WHERE with UNIQUE to enforce uniqueness over a
44 subset of a table. See Section 11.8 for more discussion.
45
46 The expression used in the WHERE clause can refer only to columns of
47 the underlying table, but it can use all columns, not just the ones
48 being indexed. Presently, subqueries and aggregate expressions are also
49 forbidden in WHERE. The same restrictions apply to index fields that
50 are expressions.
51
52 All functions and operators used in an index definition must be
53 “immutable”, that is, their results must depend only on their arguments
54 and never on any outside influence (such as the contents of another
55 table or the current time). This restriction ensures that the behavior
56 of the index is well-defined. To use a user-defined function in an
57 index expression or WHERE clause, remember to mark the function
58 immutable when you create it.
59
61 UNIQUE
62 Causes the system to check for duplicate values in the table when
63 the index is created (if data already exist) and each time data is
64 added. Attempts to insert or update data which would result in
65 duplicate entries will generate an error.
66
67 Additional restrictions apply when unique indexes are applied to
68 partitioned tables; see CREATE TABLE (CREATE_TABLE(7)).
69
70 CONCURRENTLY
71 When this option is used, PostgreSQL will build the index without
72 taking any locks that prevent concurrent inserts, updates, or
73 deletes on the table; whereas a standard index build locks out
74 writes (but not reads) on the table until it's done. There are
75 several caveats to be aware of when using this option — see
76 Building Indexes Concurrently below.
77
78 For temporary tables, CREATE INDEX is always non-concurrent, as no
79 other session can access them, and non-concurrent index creation is
80 cheaper.
81
82 IF NOT EXISTS
83 Do not throw an error if a relation with the same name already
84 exists. A notice is issued in this case. Note that there is no
85 guarantee that the existing index is anything like the one that
86 would have been created. Index name is required when IF NOT EXISTS
87 is specified.
88
89 INCLUDE
90 The optional INCLUDE clause specifies a list of columns which will
91 be included in the index as non-key columns. A non-key column
92 cannot be used in an index scan search qualification, and it is
93 disregarded for purposes of any uniqueness or exclusion constraint
94 enforced by the index. However, an index-only scan can return the
95 contents of non-key columns without having to visit the index's
96 table, since they are available directly from the index entry.
97 Thus, addition of non-key columns allows index-only scans to be
98 used for queries that otherwise could not use them.
99
100 It's wise to be conservative about adding non-key columns to an
101 index, especially wide columns. If an index tuple exceeds the
102 maximum size allowed for the index type, data insertion will fail.
103 In any case, non-key columns duplicate data from the index's table
104 and bloat the size of the index, thus potentially slowing searches.
105 Furthermore, B-tree deduplication is never used with indexes that
106 have a non-key column.
107
108 Columns listed in the INCLUDE clause don't need appropriate
109 operator classes; the clause can include columns whose data types
110 don't have operator classes defined for a given access method.
111
112 Expressions are not supported as included columns since they cannot
113 be used in index-only scans.
114
115 Currently, the B-tree, GiST and SP-GiST index access methods
116 support this feature. In these indexes, the values of columns
117 listed in the INCLUDE clause are included in leaf tuples which
118 correspond to heap tuples, but are not included in upper-level
119 index entries used for tree navigation.
120
121 name
122 The name of the index to be created. No schema name can be included
123 here; the index is always created in the same schema as its parent
124 table. If the name is omitted, PostgreSQL chooses a suitable name
125 based on the parent table's name and the indexed column name(s).
126
127 ONLY
128 Indicates not to recurse creating indexes on partitions, if the
129 table is partitioned. The default is to recurse.
130
131 table_name
132 The name (possibly schema-qualified) of the table to be indexed.
133
134 method
135 The name of the index method to be used. Choices are btree, hash,
136 gist, spgist, gin, and brin. The default method is btree.
137
138 column_name
139 The name of a column of the table.
140
141 expression
142 An expression based on one or more columns of the table. The
143 expression usually must be written with surrounding parentheses, as
144 shown in the syntax. However, the parentheses can be omitted if the
145 expression has the form of a function call.
146
147 collation
148 The name of the collation to use for the index. By default, the
149 index uses the collation declared for the column to be indexed or
150 the result collation of the expression to be indexed. Indexes with
151 non-default collations can be useful for queries that involve
152 expressions using non-default collations.
153
154 opclass
155 The name of an operator class. See below for details.
156
157 opclass_parameter
158 The name of an operator class parameter. See below for details.
159
160 ASC
161 Specifies ascending sort order (which is the default).
162
163 DESC
164 Specifies descending sort order.
165
166 NULLS FIRST
167 Specifies that nulls sort before non-nulls. This is the default
168 when DESC is specified.
169
170 NULLS LAST
171 Specifies that nulls sort after non-nulls. This is the default when
172 DESC is not specified.
173
174 storage_parameter
175 The name of an index-method-specific storage parameter. See Index
176 Storage Parameters below for details.
177
178 tablespace_name
179 The tablespace in which to create the index. If not specified,
180 default_tablespace is consulted, or temp_tablespaces for indexes on
181 temporary tables.
182
183 predicate
184 The constraint expression for a partial index.
185
186 Index Storage Parameters
187 The optional WITH clause specifies storage parameters for the index.
188 Each index method has its own set of allowed storage parameters. The
189 B-tree, hash, GiST and SP-GiST index methods all accept this parameter:
190
191 fillfactor (integer)
192 The fillfactor for an index is a percentage that determines how
193 full the index method will try to pack index pages. For B-trees,
194 leaf pages are filled to this percentage during initial index
195 builds, and also when extending the index at the right (adding new
196 largest key values). If pages subsequently become completely full,
197 they will be split, leading to fragmentation of the on-disk index
198 structure. B-trees use a default fillfactor of 90, but any integer
199 value from 10 to 100 can be selected.
200
201 B-tree indexes on tables where many inserts and/or updates are
202 anticipated can benefit from lower fillfactor settings at CREATE
203 INDEX time (following bulk loading into the table). Values in the
204 range of 50 - 90 can usefully “smooth out” the rate of page splits
205 during the early life of the B-tree index (lowering fillfactor like
206 this may even lower the absolute number of page splits, though this
207 effect is highly workload dependent). The B-tree bottom-up index
208 deletion technique described in Section 64.4.2 is dependent on
209 having some “extra” space on pages to store “extra” tuple versions,
210 and so can be affected by fillfactor (though the effect is usually
211 not significant).
212
213 In other specific cases it might be useful to increase fillfactor
214 to 100 at CREATE INDEX time as a way of maximizing space
215 utilization. You should only consider this when you are completely
216 sure that the table is static (i.e. that it will never be affected
217 by either inserts or updates). A fillfactor setting of 100
218 otherwise risks harming performance: even a few updates or inserts
219 will cause a sudden flood of page splits.
220
221 The other index methods use fillfactor in different but roughly
222 analogous ways; the default fillfactor varies between methods.
223
224 B-tree indexes additionally accept this parameter:
225
226 deduplicate_items (boolean)
227 Controls usage of the B-tree deduplication technique described in
228 Section 64.4.3. Set to ON or OFF to enable or disable the
229 optimization. (Alternative spellings of ON and OFF are allowed as
230 described in Section 20.1.) The default is ON.
231
232 Note
233 Turning deduplicate_items off via ALTER INDEX prevents future
234 insertions from triggering deduplication, but does not in
235 itself make existing posting list tuples use the standard tuple
236 representation.
237
238 GiST indexes additionally accept this parameter:
239
240 buffering (enum)
241 Determines whether the buffered build technique described in
242 Section 65.4.1 is used to build the index. With OFF buffering is
243 disabled, with ON it is enabled, and with AUTO it is initially
244 disabled, but is turned on on-the-fly once the index size reaches
245 effective_cache_size. The default is AUTO. Note that if sorted
246 build is possible, it will be used instead of buffered build unless
247 buffering=ON is specified.
248
249 GIN indexes accept different parameters:
250
251 fastupdate (boolean)
252 This setting controls usage of the fast update technique described
253 in Section 67.4.1. It is a Boolean parameter: ON enables fast
254 update, OFF disables it. The default is ON.
255
256 Note
257 Turning fastupdate off via ALTER INDEX prevents future
258 insertions from going into the list of pending index entries,
259 but does not in itself flush previous entries. You might want
260 to VACUUM the table or call gin_clean_pending_list function
261 afterward to ensure the pending list is emptied.
262
263 gin_pending_list_limit (integer)
264 Custom gin_pending_list_limit parameter. This value is specified in
265 kilobytes.
266
267 BRIN indexes accept different parameters:
268
269 pages_per_range (integer)
270 Defines the number of table blocks that make up one block range for
271 each entry of a BRIN index (see Section 68.1 for more details). The
272 default is 128.
273
274 autosummarize (boolean)
275 Defines whether a summarization run is invoked for the previous
276 page range whenever an insertion is detected on the next one.
277
278 Building Indexes Concurrently
279 Creating an index can interfere with regular operation of a database.
280 Normally PostgreSQL locks the table to be indexed against writes and
281 performs the entire index build with a single scan of the table. Other
282 transactions can still read the table, but if they try to insert,
283 update, or delete rows in the table they will block until the index
284 build is finished. This could have a severe effect if the system is a
285 live production database. Very large tables can take many hours to be
286 indexed, and even for smaller tables, an index build can lock out
287 writers for periods that are unacceptably long for a production system.
288
289 PostgreSQL supports building indexes without locking out writes. This
290 method is invoked by specifying the CONCURRENTLY option of CREATE
291 INDEX. When this option is used, PostgreSQL must perform two scans of
292 the table, and in addition it must wait for all existing transactions
293 that could potentially modify or use the index to terminate. Thus this
294 method requires more total work than a standard index build and takes
295 significantly longer to complete. However, since it allows normal
296 operations to continue while the index is built, this method is useful
297 for adding new indexes in a production environment. Of course, the
298 extra CPU and I/O load imposed by the index creation might slow other
299 operations.
300
301 In a concurrent index build, the index is actually entered into the
302 system catalogs in one transaction, then two table scans occur in two
303 more transactions. Before each table scan, the index build must wait
304 for existing transactions that have modified the table to terminate.
305 After the second scan, the index build must wait for any transactions
306 that have a snapshot (see Chapter 13) predating the second scan to
307 terminate, including transactions used by any phase of concurrent index
308 builds on other tables, if the indexes involved are partial or have
309 columns that are not simple column references. Then finally the index
310 can be marked ready for use, and the CREATE INDEX command terminates.
311 Even then, however, the index may not be immediately usable for
312 queries: in the worst case, it cannot be used as long as transactions
313 exist that predate the start of the index build.
314
315 If a problem arises while scanning the table, such as a deadlock or a
316 uniqueness violation in a unique index, the CREATE INDEX command will
317 fail but leave behind an “invalid” index. This index will be ignored
318 for querying purposes because it might be incomplete; however it will
319 still consume update overhead. The psql \d command will report such an
320 index as INVALID:
321
322 postgres=# \d tab
323 Table "public.tab"
324 Column | Type | Collation | Nullable | Default
325 --------+---------+-----------+----------+---------
326 col | integer | | |
327 Indexes:
328 "idx" btree (col) INVALID
329
330 The recommended recovery method in such cases is to drop the index and
331 try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
332 to rebuild the index with REINDEX INDEX CONCURRENTLY).
333
334 Another caveat when building a unique index concurrently is that the
335 uniqueness constraint is already being enforced against other
336 transactions when the second table scan begins. This means that
337 constraint violations could be reported in other queries prior to the
338 index becoming available for use, or even in cases where the index
339 build eventually fails. Also, if a failure does occur in the second
340 scan, the “invalid” index continues to enforce its uniqueness
341 constraint afterwards.
342
343 Concurrent builds of expression indexes and partial indexes are
344 supported. Errors occurring in the evaluation of these expressions
345 could cause behavior similar to that described above for unique
346 constraint violations.
347
348 Regular index builds permit other regular index builds on the same
349 table to occur simultaneously, but only one concurrent index build can
350 occur on a table at a time. In either case, schema modification of the
351 table is not allowed while the index is being built. Another difference
352 is that a regular CREATE INDEX command can be performed within a
353 transaction block, but CREATE INDEX CONCURRENTLY cannot.
354
355 Concurrent builds for indexes on partitioned tables are currently not
356 supported. However, you may concurrently build the index on each
357 partition individually and then finally create the partitioned index
358 non-concurrently in order to reduce the time where writes to the
359 partitioned table will be locked out. In this case, building the
360 partitioned index is a metadata only operation.
361
363 See Chapter 11 for information about when indexes can be used, when
364 they are not used, and in which particular situations they can be
365 useful.
366
367 Currently, only the B-tree, GiST, GIN, and BRIN index methods support
368 multiple-key-column indexes. Whether there can be multiple key columns
369 is independent of whether INCLUDE columns can be added to the index.
370 Indexes can have up to 32 columns, including INCLUDE columns. (This
371 limit can be altered when building PostgreSQL.) Only B-tree currently
372 supports unique indexes.
373
374 An operator class with optional parameters can be specified for each
375 column of an index. The operator class identifies the operators to be
376 used by the index for that column. For example, a B-tree index on
377 four-byte integers would use the int4_ops class; this operator class
378 includes comparison functions for four-byte integers. In practice the
379 default operator class for the column's data type is usually
380 sufficient. The main point of having operator classes is that for some
381 data types, there could be more than one meaningful ordering. For
382 example, we might want to sort a complex-number data type either by
383 absolute value or by real part. We could do this by defining two
384 operator classes for the data type and then selecting the proper class
385 when creating an index. More information about operator classes is in
386 Section 11.10 and in Section 38.16.
387
388 When CREATE INDEX is invoked on a partitioned table, the default
389 behavior is to recurse to all partitions to ensure they all have
390 matching indexes. Each partition is first checked to determine whether
391 an equivalent index already exists, and if so, that index will become
392 attached as a partition index to the index being created, which will
393 become its parent index. If no matching index exists, a new index will
394 be created and automatically attached; the name of the new index in
395 each partition will be determined as if no index name had been
396 specified in the command. If the ONLY option is specified, no recursion
397 is done, and the index is marked invalid. (ALTER INDEX ... ATTACH
398 PARTITION marks the index valid, once all partitions acquire matching
399 indexes.) Note, however, that any partition that is created in the
400 future using CREATE TABLE ... PARTITION OF will automatically have a
401 matching index, regardless of whether ONLY is specified.
402
403 For index methods that support ordered scans (currently, only B-tree),
404 the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
405 specified to modify the sort ordering of the index. Since an ordered
406 index can be scanned either forward or backward, it is not normally
407 useful to create a single-column DESC index — that sort ordering is
408 already available with a regular index. The value of these options is
409 that multicolumn indexes can be created that match the sort ordering
410 requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
411 y DESC. The NULLS options are useful if you need to support “nulls sort
412 low” behavior, rather than the default “nulls sort high”, in queries
413 that depend on indexes to avoid sorting steps.
414
415 The system regularly collects statistics on all of a table's columns.
416 Newly-created non-expression indexes can immediately use these
417 statistics to determine an index's usefulness. For new expression
418 indexes, it is necessary to run ANALYZE or wait for the autovacuum
419 daemon to analyze the table to generate statistics for these indexes.
420
421 For most index methods, the speed of creating an index is dependent on
422 the setting of maintenance_work_mem. Larger values will reduce the time
423 needed for index creation, so long as you don't make it larger than the
424 amount of memory really available, which would drive the machine into
425 swapping.
426
427 PostgreSQL can build indexes while leveraging multiple CPUs in order to
428 process the table rows faster. This feature is known as parallel index
429 build. For index methods that support building indexes in parallel
430 (currently, only B-tree), maintenance_work_mem specifies the maximum
431 amount of memory that can be used by each index build operation as a
432 whole, regardless of how many worker processes were started. Generally,
433 a cost model automatically determines how many worker processes should
434 be requested, if any.
435
436 Parallel index builds may benefit from increasing maintenance_work_mem
437 where an equivalent serial index build will see little or no benefit.
438 Note that maintenance_work_mem may influence the number of worker
439 processes requested, since parallel workers must have at least a 32MB
440 share of the total maintenance_work_mem budget. There must also be a
441 remaining 32MB share for the leader process. Increasing
442 max_parallel_maintenance_workers may allow more workers to be used,
443 which will reduce the time needed for index creation, so long as the
444 index build is not already I/O bound. Of course, there should also be
445 sufficient CPU capacity that would otherwise lie idle.
446
447 Setting a value for parallel_workers via ALTER TABLE directly controls
448 how many parallel worker processes will be requested by a CREATE INDEX
449 against the table. This bypasses the cost model completely, and
450 prevents maintenance_work_mem from affecting how many parallel workers
451 are requested. Setting parallel_workers to 0 via ALTER TABLE will
452 disable parallel index builds on the table in all cases.
453
454 Tip
455 You might want to reset parallel_workers after setting it as part
456 of tuning an index build. This avoids inadvertent changes to query
457 plans, since parallel_workers affects all parallel table scans.
458
459 While CREATE INDEX with the CONCURRENTLY option supports parallel
460 builds without special restrictions, only the first table scan is
461 actually performed in parallel.
462
463 Use DROP INDEX to remove an index.
464
465 Like any long-running transaction, CREATE INDEX on a table can affect
466 which tuples can be removed by concurrent VACUUM on any other table.
467 Excepted from this are operations with the CONCURRENTLY option for
468 indexes that are not partial and do not index any expressions.
469
470 Prior releases of PostgreSQL also had an R-tree index method. This
471 method has been removed because it had no significant advantages over
472 the GiST method. If USING rtree is specified, CREATE INDEX will
473 interpret it as USING gist, to simplify conversion of old databases to
474 GiST.
475
476 Each backend running CREATE INDEX will report its progress in the
477 pg_stat_progress_create_index view. See Section 28.4.2 for details.
478
480 To create a unique B-tree index on the column title in the table films:
481
482 CREATE UNIQUE INDEX title_idx ON films (title);
483
484 To create a unique B-tree index on the column title with included
485 columns director and rating in the table films:
486
487 CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
488
489 To create a B-Tree index with deduplication disabled:
490
491 CREATE INDEX title_idx ON films (title) WITH (deduplicate_items = off);
492
493 To create an index on the expression lower(title), allowing efficient
494 case-insensitive searches:
495
496 CREATE INDEX ON films ((lower(title)));
497
498 (In this example we have chosen to omit the index name, so the system
499 will choose a name, typically films_lower_idx.)
500
501 To create an index with non-default collation:
502
503 CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
504
505 To create an index with non-default sort ordering of nulls:
506
507 CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
508
509 To create an index with non-default fill factor:
510
511 CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
512
513 To create a GIN index with fast updates disabled:
514
515 CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
516
517 To create an index on the column code in the table films and have the
518 index reside in the tablespace indexspace:
519
520 CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
521
522 To create a GiST index on a point attribute so that we can efficiently
523 use box operators on the result of the conversion function:
524
525 CREATE INDEX pointloc
526 ON points USING gist (box(location,location));
527 SELECT * FROM points
528 WHERE box(location,location) && '(0,0),(1,1)'::box;
529
530 To create an index without locking out writes to the table:
531
532 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
533
535 CREATE INDEX is a PostgreSQL language extension. There are no
536 provisions for indexes in the SQL standard.
537
539 ALTER INDEX (ALTER_INDEX(7)), DROP INDEX (DROP_INDEX(7)), REINDEX(7),
540 Section 28.4.2
541
542
543
544PostgreSQL 14.3 2022 CREATE INDEX(7)