1CREATE INDEX(7)          PostgreSQL 15.4 Documentation         CREATE INDEX(7)
2
3
4

NAME

6       CREATE_INDEX - define a new index
7

SYNOPSIS

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           [ NULLS [ NOT ] DISTINCT ]
13           [ WITH ( storage_parameter [= value] [, ... ] ) ]
14           [ TABLESPACE tablespace_name ]
15           [ WHERE predicate ]
16

DESCRIPTION

18       CREATE INDEX constructs an index on the specified column(s) of the
19       specified relation, which can be a table or a materialized view.
20       Indexes are primarily used to enhance database performance (though
21       inappropriate use can result in slower performance).
22
23       The key field(s) for the index are specified as column names, or
24       alternatively as expressions written in parentheses. Multiple fields
25       can be specified if the index method supports multicolumn indexes.
26
27       An index field can be an expression computed from the values of one or
28       more columns of the table row. This feature can be used to obtain fast
29       access to data based on some transformation of the basic data. For
30       example, an index computed on upper(col) would allow the clause WHERE
31       upper(col) = 'JIM' to use an index.
32
33       PostgreSQL provides the index methods B-tree, hash, GiST, SP-GiST, GIN,
34       and BRIN. Users can also define their own index methods, but that is
35       fairly complicated.
36
37       When the WHERE clause is present, a partial index is created. A partial
38       index is an index that contains entries for only a portion of a table,
39       usually a portion that is more useful for indexing than the rest of the
40       table. For example, if you have a table that contains both billed and
41       unbilled orders where the unbilled orders take up a small fraction of
42       the total table and yet that is an often used section, you can improve
43       performance by creating an index on just that portion. Another possible
44       application is to use WHERE with UNIQUE to enforce uniqueness over a
45       subset of a table. See Section 11.8 for more discussion.
46
47       The expression used in the WHERE clause can refer only to columns of
48       the underlying table, but it can use all columns, not just the ones
49       being indexed. Presently, subqueries and aggregate expressions are also
50       forbidden in WHERE. The same restrictions apply to index fields that
51       are expressions.
52
53       All functions and operators used in an index definition must be
54       “immutable”, that is, their results must depend only on their arguments
55       and never on any outside influence (such as the contents of another
56       table or the current time). This restriction ensures that the behavior
57       of the index is well-defined. To use a user-defined function in an
58       index expression or WHERE clause, remember to mark the function
59       immutable when you create it.
60

PARAMETERS

62       UNIQUE
63           Causes the system to check for duplicate values in the table when
64           the index is created (if data already exist) and each time data is
65           added. Attempts to insert or update data which would result in
66           duplicate entries will generate an error.
67
68           Additional restrictions apply when unique indexes are applied to
69           partitioned tables; see CREATE TABLE (CREATE_TABLE(7)).
70
71       CONCURRENTLY
72           When this option is used, PostgreSQL will build the index without
73           taking any locks that prevent concurrent inserts, updates, or
74           deletes on the table; whereas a standard index build locks out
75           writes (but not reads) on the table until it's done. There are
76           several caveats to be aware of when using this option — see
77           Building Indexes Concurrently below.
78
79           For temporary tables, CREATE INDEX is always non-concurrent, as no
80           other session can access them, and non-concurrent index creation is
81           cheaper.
82
83       IF NOT EXISTS
84           Do not throw an error if a relation with the same name already
85           exists. A notice is issued in this case. Note that there is no
86           guarantee that the existing index is anything like the one that
87           would have been created. Index name is required when IF NOT EXISTS
88           is specified.
89
90       INCLUDE
91           The optional INCLUDE clause specifies a list of columns which will
92           be included in the index as non-key columns. A non-key column
93           cannot be used in an index scan search qualification, and it is
94           disregarded for purposes of any uniqueness or exclusion constraint
95           enforced by the index. However, an index-only scan can return the
96           contents of non-key columns without having to visit the index's
97           table, since they are available directly from the index entry.
98           Thus, addition of non-key columns allows index-only scans to be
99           used for queries that otherwise could not use them.
100
101           It's wise to be conservative about adding non-key columns to an
102           index, especially wide columns. If an index tuple exceeds the
103           maximum size allowed for the index type, data insertion will fail.
104           In any case, non-key columns duplicate data from the index's table
105           and bloat the size of the index, thus potentially slowing searches.
106           Furthermore, B-tree deduplication is never used with indexes that
107           have a non-key column.
108
109           Columns listed in the INCLUDE clause don't need appropriate
110           operator classes; the clause can include columns whose data types
111           don't have operator classes defined for a given access method.
112
113           Expressions are not supported as included columns since they cannot
114           be used in index-only scans.
115
116           Currently, the B-tree, GiST and SP-GiST index access methods
117           support this feature. In these indexes, the values of columns
118           listed in the INCLUDE clause are included in leaf tuples which
119           correspond to heap tuples, but are not included in upper-level
120           index entries used for tree navigation.
121
122       name
123           The name of the index to be created. No schema name can be included
124           here; the index is always created in the same schema as its parent
125           table. The name of the index must be distinct from the name of any
126           other relation (table, sequence, index, view, materialized view, or
127           foreign table) in that schema. If the name is omitted, PostgreSQL
128           chooses a suitable name based on the parent table's name and the
129           indexed column name(s).
130
131       ONLY
132           Indicates not to recurse creating indexes on partitions, if the
133           table is partitioned. The default is to recurse.
134
135       table_name
136           The name (possibly schema-qualified) of the table to be indexed.
137
138       method
139           The name of the index method to be used. Choices are btree, hash,
140           gist, spgist, gin, brin, or user-installed access methods like
141           bloom. The default method is btree.
142
143       column_name
144           The name of a column of the table.
145
146       expression
147           An expression based on one or more columns of the table. The
148           expression usually must be written with surrounding parentheses, as
149           shown in the syntax. However, the parentheses can be omitted if the
150           expression has the form of a function call.
151
152       collation
153           The name of the collation to use for the index. By default, the
154           index uses the collation declared for the column to be indexed or
155           the result collation of the expression to be indexed. Indexes with
156           non-default collations can be useful for queries that involve
157           expressions using non-default collations.
158
159       opclass
160           The name of an operator class. See below for details.
161
162       opclass_parameter
163           The name of an operator class parameter. See below for details.
164
165       ASC
166           Specifies ascending sort order (which is the default).
167
168       DESC
169           Specifies descending sort order.
170
171       NULLS FIRST
172           Specifies that nulls sort before non-nulls. This is the default
173           when DESC is specified.
174
175       NULLS LAST
176           Specifies that nulls sort after non-nulls. This is the default when
177           DESC is not specified.
178
179       NULLS DISTINCT
180       NULLS NOT DISTINCT
181           Specifies whether for a unique index, null values should be
182           considered distinct (not equal). The default is that they are
183           distinct, so that a unique index could contain multiple null values
184           in a column.
185
186       storage_parameter
187           The name of an index-method-specific storage parameter. See Index
188           Storage Parameters below for details.
189
190       tablespace_name
191           The tablespace in which to create the index. If not specified,
192           default_tablespace is consulted, or temp_tablespaces for indexes on
193           temporary tables.
194
195       predicate
196           The constraint expression for a partial index.
197
198   Index Storage Parameters
199       The optional WITH clause specifies storage parameters for the index.
200       Each index method has its own set of allowed storage parameters. The
201       B-tree, hash, GiST and SP-GiST index methods all accept this parameter:
202
203       fillfactor (integer)
204           The fillfactor for an index is a percentage that determines how
205           full the index method will try to pack index pages. For B-trees,
206           leaf pages are filled to this percentage during initial index
207           builds, and also when extending the index at the right (adding new
208           largest key values). If pages subsequently become completely full,
209           they will be split, leading to fragmentation of the on-disk index
210           structure. B-trees use a default fillfactor of 90, but any integer
211           value from 10 to 100 can be selected.
212
213           B-tree indexes on tables where many inserts and/or updates are
214           anticipated can benefit from lower fillfactor settings at CREATE
215           INDEX time (following bulk loading into the table). Values in the
216           range of 50 - 90 can usefully “smooth out” the rate of page splits
217           during the early life of the B-tree index (lowering fillfactor like
218           this may even lower the absolute number of page splits, though this
219           effect is highly workload dependent). The B-tree bottom-up index
220           deletion technique described in Section 67.4.2 is dependent on
221           having some “extra” space on pages to store “extra” tuple versions,
222           and so can be affected by fillfactor (though the effect is usually
223           not significant).
224
225           In other specific cases it might be useful to increase fillfactor
226           to 100 at CREATE INDEX time as a way of maximizing space
227           utilization. You should only consider this when you are completely
228           sure that the table is static (i.e. that it will never be affected
229           by either inserts or updates). A fillfactor setting of 100
230           otherwise risks harming performance: even a few updates or inserts
231           will cause a sudden flood of page splits.
232
233           The other index methods use fillfactor in different but roughly
234           analogous ways; the default fillfactor varies between methods.
235
236       B-tree indexes additionally accept this parameter:
237
238       deduplicate_items (boolean)
239           Controls usage of the B-tree deduplication technique described in
240           Section 67.4.3. Set to ON or OFF to enable or disable the
241           optimization. (Alternative spellings of ON and OFF are allowed as
242           described in Section 20.1.) The default is ON.
243
244               Note
245               Turning deduplicate_items off via ALTER INDEX prevents future
246               insertions from triggering deduplication, but does not in
247               itself make existing posting list tuples use the standard tuple
248               representation.
249
250       GiST indexes additionally accept this parameter:
251
252       buffering (enum)
253           Determines whether the buffered build technique described in
254           Section 68.4.1 is used to build the index. With OFF buffering is
255           disabled, with ON it is enabled, and with AUTO it is initially
256           disabled, but is turned on on-the-fly once the index size reaches
257           effective_cache_size. The default is AUTO. Note that if sorted
258           build is possible, it will be used instead of buffered build unless
259           buffering=ON is specified.
260
261       GIN indexes accept different parameters:
262
263       fastupdate (boolean)
264           This setting controls usage of the fast update technique described
265           in Section 70.4.1. It is a Boolean parameter: ON enables fast
266           update, OFF disables it. The default is ON.
267
268               Note
269               Turning fastupdate off via ALTER INDEX prevents future
270               insertions from going into the list of pending index entries,
271               but does not in itself flush previous entries. You might want
272               to VACUUM the table or call gin_clean_pending_list function
273               afterward to ensure the pending list is emptied.
274
275       gin_pending_list_limit (integer)
276           Custom gin_pending_list_limit parameter. This value is specified in
277           kilobytes.
278
279       BRIN indexes accept different parameters:
280
281       pages_per_range (integer)
282           Defines the number of table blocks that make up one block range for
283           each entry of a BRIN index (see Section 71.1 for more details). The
284           default is 128.
285
286       autosummarize (boolean)
287           Defines whether a summarization run is queued for the previous page
288           range whenever an insertion is detected on the next one. See
289           Section 71.1.1 for more details. The default is off.
290
291   Building Indexes Concurrently
292       Creating an index can interfere with regular operation of a database.
293       Normally PostgreSQL locks the table to be indexed against writes and
294       performs the entire index build with a single scan of the table. Other
295       transactions can still read the table, but if they try to insert,
296       update, or delete rows in the table they will block until the index
297       build is finished. This could have a severe effect if the system is a
298       live production database. Very large tables can take many hours to be
299       indexed, and even for smaller tables, an index build can lock out
300       writers for periods that are unacceptably long for a production system.
301
302       PostgreSQL supports building indexes without locking out writes. This
303       method is invoked by specifying the CONCURRENTLY option of CREATE
304       INDEX. When this option is used, PostgreSQL must perform two scans of
305       the table, and in addition it must wait for all existing transactions
306       that could potentially modify or use the index to terminate. Thus this
307       method requires more total work than a standard index build and takes
308       significantly longer to complete. However, since it allows normal
309       operations to continue while the index is built, this method is useful
310       for adding new indexes in a production environment. Of course, the
311       extra CPU and I/O load imposed by the index creation might slow other
312       operations.
313
314       In a concurrent index build, the index is actually entered as an
315       “invalid” index into the system catalogs in one transaction, then two
316       table scans occur in two more transactions. Before each table scan, the
317       index build must wait for existing transactions that have modified the
318       table to terminate. After the second scan, the index build must wait
319       for any transactions that have a snapshot (see Chapter 13) predating
320       the second scan to terminate, including transactions used by any phase
321       of concurrent index builds on other tables, if the indexes involved are
322       partial or have columns that are not simple column references. Then
323       finally the index can be marked “valid” and ready for use, and the
324       CREATE INDEX command terminates. Even then, however, the index may not
325       be immediately usable for queries: in the worst case, it cannot be used
326       as long as transactions exist that predate the start of the index
327       build.
328
329       If a problem arises while scanning the table, such as a deadlock or a
330       uniqueness violation in a unique index, the CREATE INDEX command will
331       fail but leave behind an “invalid” index. This index will be ignored
332       for querying purposes because it might be incomplete; however it will
333       still consume update overhead. The psql \d command will report such an
334       index as INVALID:
335
336           postgres=# \d tab
337                  Table "public.tab"
338            Column |  Type   | Collation | Nullable | Default
339           --------+---------+-----------+----------+---------
340            col    | integer |           |          |
341           Indexes:
342               "idx" btree (col) INVALID
343
344       The recommended recovery method in such cases is to drop the index and
345       try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
346       to rebuild the index with REINDEX INDEX CONCURRENTLY).
347
348       Another caveat when building a unique index concurrently is that the
349       uniqueness constraint is already being enforced against other
350       transactions when the second table scan begins. This means that
351       constraint violations could be reported in other queries prior to the
352       index becoming available for use, or even in cases where the index
353       build eventually fails. Also, if a failure does occur in the second
354       scan, the “invalid” index continues to enforce its uniqueness
355       constraint afterwards.
356
357       Concurrent builds of expression indexes and partial indexes are
358       supported. Errors occurring in the evaluation of these expressions
359       could cause behavior similar to that described above for unique
360       constraint violations.
361
362       Regular index builds permit other regular index builds on the same
363       table to occur simultaneously, but only one concurrent index build can
364       occur on a table at a time. In either case, schema modification of the
365       table is not allowed while the index is being built. Another difference
366       is that a regular CREATE INDEX command can be performed within a
367       transaction block, but CREATE INDEX CONCURRENTLY cannot.
368
369       Concurrent builds for indexes on partitioned tables are currently not
370       supported. However, you may concurrently build the index on each
371       partition individually and then finally create the partitioned index
372       non-concurrently in order to reduce the time where writes to the
373       partitioned table will be locked out. In this case, building the
374       partitioned index is a metadata only operation.
375

NOTES

377       See Chapter 11 for information about when indexes can be used, when
378       they are not used, and in which particular situations they can be
379       useful.
380
381       Currently, only the B-tree, GiST, GIN, and BRIN index methods support
382       multiple-key-column indexes. Whether there can be multiple key columns
383       is independent of whether INCLUDE columns can be added to the index.
384       Indexes can have up to 32 columns, including INCLUDE columns. (This
385       limit can be altered when building PostgreSQL.) Only B-tree currently
386       supports unique indexes.
387
388       An operator class with optional parameters can be specified for each
389       column of an index. The operator class identifies the operators to be
390       used by the index for that column. For example, a B-tree index on
391       four-byte integers would use the int4_ops class; this operator class
392       includes comparison functions for four-byte integers. In practice the
393       default operator class for the column's data type is usually
394       sufficient. The main point of having operator classes is that for some
395       data types, there could be more than one meaningful ordering. For
396       example, we might want to sort a complex-number data type either by
397       absolute value or by real part. We could do this by defining two
398       operator classes for the data type and then selecting the proper class
399       when creating an index. More information about operator classes is in
400       Section 11.10 and in Section 38.16.
401
402       When CREATE INDEX is invoked on a partitioned table, the default
403       behavior is to recurse to all partitions to ensure they all have
404       matching indexes. Each partition is first checked to determine whether
405       an equivalent index already exists, and if so, that index will become
406       attached as a partition index to the index being created, which will
407       become its parent index. If no matching index exists, a new index will
408       be created and automatically attached; the name of the new index in
409       each partition will be determined as if no index name had been
410       specified in the command. If the ONLY option is specified, no recursion
411       is done, and the index is marked invalid. (ALTER INDEX ... ATTACH
412       PARTITION marks the index valid, once all partitions acquire matching
413       indexes.) Note, however, that any partition that is created in the
414       future using CREATE TABLE ... PARTITION OF will automatically have a
415       matching index, regardless of whether ONLY is specified.
416
417       For index methods that support ordered scans (currently, only B-tree),
418       the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
419       specified to modify the sort ordering of the index. Since an ordered
420       index can be scanned either forward or backward, it is not normally
421       useful to create a single-column DESC index — that sort ordering is
422       already available with a regular index. The value of these options is
423       that multicolumn indexes can be created that match the sort ordering
424       requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
425       y DESC. The NULLS options are useful if you need to support “nulls sort
426       low” behavior, rather than the default “nulls sort high”, in queries
427       that depend on indexes to avoid sorting steps.
428
429       The system regularly collects statistics on all of a table's columns.
430       Newly-created non-expression indexes can immediately use these
431       statistics to determine an index's usefulness. For new expression
432       indexes, it is necessary to run ANALYZE or wait for the autovacuum
433       daemon to analyze the table to generate statistics for these indexes.
434
435       For most index methods, the speed of creating an index is dependent on
436       the setting of maintenance_work_mem. Larger values will reduce the time
437       needed for index creation, so long as you don't make it larger than the
438       amount of memory really available, which would drive the machine into
439       swapping.
440
441       PostgreSQL can build indexes while leveraging multiple CPUs in order to
442       process the table rows faster. This feature is known as parallel index
443       build. For index methods that support building indexes in parallel
444       (currently, only B-tree), maintenance_work_mem specifies the maximum
445       amount of memory that can be used by each index build operation as a
446       whole, regardless of how many worker processes were started. Generally,
447       a cost model automatically determines how many worker processes should
448       be requested, if any.
449
450       Parallel index builds may benefit from increasing maintenance_work_mem
451       where an equivalent serial index build will see little or no benefit.
452       Note that maintenance_work_mem may influence the number of worker
453       processes requested, since parallel workers must have at least a 32MB
454       share of the total maintenance_work_mem budget. There must also be a
455       remaining 32MB share for the leader process. Increasing
456       max_parallel_maintenance_workers may allow more workers to be used,
457       which will reduce the time needed for index creation, so long as the
458       index build is not already I/O bound. Of course, there should also be
459       sufficient CPU capacity that would otherwise lie idle.
460
461       Setting a value for parallel_workers via ALTER TABLE directly controls
462       how many parallel worker processes will be requested by a CREATE INDEX
463       against the table. This bypasses the cost model completely, and
464       prevents maintenance_work_mem from affecting how many parallel workers
465       are requested. Setting parallel_workers to 0 via ALTER TABLE will
466       disable parallel index builds on the table in all cases.
467
468           Tip
469           You might want to reset parallel_workers after setting it as part
470           of tuning an index build. This avoids inadvertent changes to query
471           plans, since parallel_workers affects all parallel table scans.
472
473       While CREATE INDEX with the CONCURRENTLY option supports parallel
474       builds without special restrictions, only the first table scan is
475       actually performed in parallel.
476
477       Use DROP INDEX to remove an index.
478
479       Like any long-running transaction, CREATE INDEX on a table can affect
480       which tuples can be removed by concurrent VACUUM on any other table.
481
482       Prior releases of PostgreSQL also had an R-tree index method. This
483       method has been removed because it had no significant advantages over
484       the GiST method. If USING rtree is specified, CREATE INDEX will
485       interpret it as USING gist, to simplify conversion of old databases to
486       GiST.
487
488       Each backend running CREATE INDEX will report its progress in the
489       pg_stat_progress_create_index view. See Section 28.4.2 for details.
490

EXAMPLES

492       To create a unique B-tree index on the column title in the table films:
493
494           CREATE UNIQUE INDEX title_idx ON films (title);
495
496       To create a unique B-tree index on the column title with included
497       columns director and rating in the table films:
498
499           CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
500
501       To create a B-Tree index with deduplication disabled:
502
503           CREATE INDEX title_idx ON films (title) WITH (deduplicate_items = off);
504
505       To create an index on the expression lower(title), allowing efficient
506       case-insensitive searches:
507
508           CREATE INDEX ON films ((lower(title)));
509
510       (In this example we have chosen to omit the index name, so the system
511       will choose a name, typically films_lower_idx.)
512
513       To create an index with non-default collation:
514
515           CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
516
517       To create an index with non-default sort ordering of nulls:
518
519           CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
520
521       To create an index with non-default fill factor:
522
523           CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
524
525       To create a GIN index with fast updates disabled:
526
527           CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
528
529       To create an index on the column code in the table films and have the
530       index reside in the tablespace indexspace:
531
532           CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
533
534       To create a GiST index on a point attribute so that we can efficiently
535       use box operators on the result of the conversion function:
536
537           CREATE INDEX pointloc
538               ON points USING gist (box(location,location));
539           SELECT * FROM points
540               WHERE box(location,location) && '(0,0),(1,1)'::box;
541
542       To create an index without locking out writes to the table:
543
544           CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
545

COMPATIBILITY

547       CREATE INDEX is a PostgreSQL language extension. There are no
548       provisions for indexes in the SQL standard.
549

SEE ALSO

551       ALTER INDEX (ALTER_INDEX(7)), DROP INDEX (DROP_INDEX(7)), REINDEX(7),
552       Section 28.4.2
553
554
555
556PostgreSQL 15.4                      2023                      CREATE INDEX(7)
Impressum