1CREATE INDEX(7)          PostgreSQL 11.3 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 ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
11           [ INCLUDE ( column_name [, ...] ) ]
12           [ WITH ( storage_parameter = value [, ... ] ) ]
13           [ TABLESPACE tablespace_name ]
14           [ WHERE predicate ]
15

DESCRIPTION

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

PARAMETERS

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.
77
78       IF NOT EXISTS
79           Do not throw an error if a relation with the same name already
80           exists. A notice is issued in this case. Note that there is no
81           guarantee that the existing index is anything like the one that
82           would have been created. Index name is required when IF NOT EXISTS
83           is specified.
84
85       INCLUDE
86           The optional INCLUDE clause specifies a list of columns which will
87           be included in the index as non-key columns. A non-key column
88           cannot be used in an index scan search qualification, and it is
89           disregarded for purposes of any uniqueness or exclusion constraint
90           enforced by the index. However, an index-only scan can return the
91           contents of non-key columns without having to visit the index's
92           table, since they are available directly from the index entry.
93           Thus, addition of non-key columns allows index-only scans to be
94           used for queries that otherwise could not use them.
95
96           It's wise to be conservative about adding non-key columns to an
97           index, especially wide columns. If an index tuple exceeds the
98           maximum size allowed for the index type, data insertion will fail.
99           In any case, non-key columns duplicate data from the index's table
100           and bloat the size of the index, thus potentially slowing searches.
101
102           Columns listed in the INCLUDE clause don't need appropriate
103           operator classes; the clause can include columns whose data types
104           don't have operator classes defined for a given access method.
105
106           Expressions are not supported as included columns since they cannot
107           be used in index-only scans.
108
109           Currently, only the B-tree index access method supports this
110           feature. In B-tree indexes, the values of columns listed in the
111           INCLUDE clause are included in leaf tuples which correspond to heap
112           tuples, but are not included in upper-level index entries used for
113           tree navigation.
114
115       name
116           The name of the index to be created. No schema name can be included
117           here; the index is always created in the same schema as its parent
118           table. If the name is omitted, PostgreSQL chooses a suitable name
119           based on the parent table's name and the indexed column name(s).
120
121       ONLY
122           Indicates not to recurse creating indexes on partitions, if the
123           table is partitioned. The default is to recurse.
124
125       table_name
126           The name (possibly schema-qualified) of the table to be indexed.
127
128       method
129           The name of the index method to be used. Choices are btree, hash,
130           gist, spgist, gin, and brin. The default method is btree.
131
132       column_name
133           The name of a column of the table.
134
135       expression
136           An expression based on one or more columns of the table. The
137           expression usually must be written with surrounding parentheses, as
138           shown in the syntax. However, the parentheses can be omitted if the
139           expression has the form of a function call.
140
141       collation
142           The name of the collation to use for the index. By default, the
143           index uses the collation declared for the column to be indexed or
144           the result collation of the expression to be indexed. Indexes with
145           non-default collations can be useful for queries that involve
146           expressions using non-default collations.
147
148       opclass
149           The name of an operator class. See below for details.
150
151       ASC
152           Specifies ascending sort order (which is the default).
153
154       DESC
155           Specifies descending sort order.
156
157       NULLS FIRST
158           Specifies that nulls sort before non-nulls. This is the default
159           when DESC is specified.
160
161       NULLS LAST
162           Specifies that nulls sort after non-nulls. This is the default when
163           DESC is not specified.
164
165       storage_parameter
166           The name of an index-method-specific storage parameter. See Index
167           Storage Parameters for details.
168
169       tablespace_name
170           The tablespace in which to create the index. If not specified,
171           default_tablespace is consulted, or temp_tablespaces for indexes on
172           temporary tables.
173
174       predicate
175           The constraint expression for a partial index.
176
177   Index Storage Parameters
178       The optional WITH clause specifies storage parameters for the index.
179       Each index method has its own set of allowed storage parameters. The
180       B-tree, hash, GiST and SP-GiST index methods all accept this parameter:
181
182       fillfactor
183           The fillfactor for an index is a percentage that determines how
184           full the index method will try to pack index pages. For B-trees,
185           leaf pages are filled to this percentage during initial index
186           build, and also when extending the index at the right (adding new
187           largest key values). If pages subsequently become completely full,
188           they will be split, leading to gradual degradation in the index's
189           efficiency. B-trees use a default fillfactor of 90, but any integer
190           value from 10 to 100 can be selected. If the table is static then
191           fillfactor 100 is best to minimize the index's physical size, but
192           for heavily updated tables a smaller fillfactor is better to
193           minimize the need for page splits. The other index methods use
194           fillfactor in different but roughly analogous ways; the default
195           fillfactor varies between methods.
196
197       B-tree indexes additionally accept this parameter:
198
199       vacuum_cleanup_index_scale_factor
200           Per-index value for vacuum_cleanup_index_scale_factor.
201
202       GiST indexes additionally accept this parameter:
203
204       buffering
205           Determines whether the buffering build technique described in
206           Section 64.4.1 is used to build the index. With OFF it is disabled,
207           with ON it is enabled, and with AUTO it is initially disabled, but
208           turned on on-the-fly once the index size reaches
209           effective_cache_size. The default is AUTO.
210
211       GIN indexes accept different parameters:
212
213       fastupdate
214           This setting controls usage of the fast update technique described
215           in Section 66.4.1. It is a Boolean parameter: ON enables fast
216           update, OFF disables it. (Alternative spellings of ON and OFF are
217           allowed as described in Section 19.1.) The default is ON.
218
219               Note
220               Turning fastupdate off via ALTER INDEX prevents future
221               insertions from going into the list of pending index entries,
222               but does not in itself flush previous entries. You might want
223               to VACUUM the table or call gin_clean_pending_list function
224               afterward to ensure the pending list is emptied.
225
226       gin_pending_list_limit
227           Custom gin_pending_list_limit parameter. This value is specified in
228           kilobytes.
229
230       BRIN indexes accept different parameters:
231
232       pages_per_range
233           Defines the number of table blocks that make up one block range for
234           each entry of a BRIN index (see Section 67.1 for more details). The
235           default is 128.
236
237       autosummarize
238           Defines whether a summarization run is invoked for the previous
239           page range whenever an insertion is detected on the next one.
240
241   Building Indexes Concurrently
242       Creating an index can interfere with regular operation of a database.
243       Normally PostgreSQL locks the table to be indexed against writes and
244       performs the entire index build with a single scan of the table. Other
245       transactions can still read the table, but if they try to insert,
246       update, or delete rows in the table they will block until the index
247       build is finished. This could have a severe effect if the system is a
248       live production database. Very large tables can take many hours to be
249       indexed, and even for smaller tables, an index build can lock out
250       writers for periods that are unacceptably long for a production system.
251
252       PostgreSQL supports building indexes without locking out writes. This
253       method is invoked by specifying the CONCURRENTLY option of CREATE
254       INDEX. When this option is used, PostgreSQL must perform two scans of
255       the table, and in addition it must wait for all existing transactions
256       that could potentially modify or use the index to terminate. Thus this
257       method requires more total work than a standard index build and takes
258       significantly longer to complete. However, since it allows normal
259       operations to continue while the index is built, this method is useful
260       for adding new indexes in a production environment. Of course, the
261       extra CPU and I/O load imposed by the index creation might slow other
262       operations.
263
264       In a concurrent index build, the index is actually entered into the
265       system catalogs in one transaction, then two table scans occur in two
266       more transactions. Before each table scan, the index build must wait
267       for existing transactions that have modified the table to terminate.
268       After the second scan, the index build must wait for any transactions
269       that have a snapshot (see Chapter 13) predating the second scan to
270       terminate. Then finally the index can be marked ready for use, and the
271       CREATE INDEX command terminates. Even then, however, the index may not
272       be immediately usable for queries: in the worst case, it cannot be used
273       as long as transactions exist that predate the start of the index
274       build.
275
276       If a problem arises while scanning the table, such as a deadlock or a
277       uniqueness violation in a unique index, the CREATE INDEX command will
278       fail but leave behind an “invalid” index. This index will be ignored
279       for querying purposes because it might be incomplete; however it will
280       still consume update overhead. The psql \d command will report such an
281       index as INVALID:
282
283           postgres=# \d tab
284                  Table "public.tab"
285            Column |  Type   | Collation | Nullable | Default
286           --------+---------+-----------+----------+---------
287            col    | integer |           |          |
288           Indexes:
289               "idx" btree (col) INVALID
290
291       The recommended recovery method in such cases is to drop the index and
292       try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
293       to rebuild the index with REINDEX. However, since REINDEX does not
294       support concurrent builds, this option is unlikely to seem attractive.)
295
296       Another caveat when building a unique index concurrently is that the
297       uniqueness constraint is already being enforced against other
298       transactions when the second table scan begins. This means that
299       constraint violations could be reported in other queries prior to the
300       index becoming available for use, or even in cases where the index
301       build eventually fails. Also, if a failure does occur in the second
302       scan, the “invalid” index continues to enforce its uniqueness
303       constraint afterwards.
304
305       Concurrent builds of expression indexes and partial indexes are
306       supported. Errors occurring in the evaluation of these expressions
307       could cause behavior similar to that described above for unique
308       constraint violations.
309
310       Regular index builds permit other regular index builds on the same
311       table to occur simultaneously, but only one concurrent index build can
312       occur on a table at a time. In either case, schema modification of the
313       table is not allowed while the index is being built. Another difference
314       is that a regular CREATE INDEX command can be performed within a
315       transaction block, but CREATE INDEX CONCURRENTLY cannot.
316

NOTES

318       See Chapter 11 for information about when indexes can be used, when
319       they are not used, and in which particular situations they can be
320       useful.
321
322       Currently, only the B-tree, GiST, GIN, and BRIN index methods support
323       multicolumn indexes. Up to 32 fields can be specified by default. (This
324       limit can be altered when building PostgreSQL.) Only B-tree currently
325       supports unique indexes.
326
327       An operator class can be specified for each column of an index. The
328       operator class identifies the operators to be used by the index for
329       that column. For example, a B-tree index on four-byte integers would
330       use the int4_ops class; this operator class includes comparison
331       functions for four-byte integers. In practice the default operator
332       class for the column's data type is usually sufficient. The main point
333       of having operator classes is that for some data types, there could be
334       more than one meaningful ordering. For example, we might want to sort a
335       complex-number data type either by absolute value or by real part. We
336       could do this by defining two operator classes for the data type and
337       then selecting the proper class when creating an index. More
338       information about operator classes is in Section 11.10 and in
339       Section 38.15.
340
341       When CREATE INDEX is invoked on a partitioned table, the default
342       behavior is to recurse to all partitions to ensure they all have
343       matching indexes. Each partition is first checked to determine whether
344       an equivalent index already exists, and if so, that index will become
345       attached as a partition index to the index being created, which will
346       become its parent index. If no matching index exists, a new index will
347       be created and automatically attached; the name of the new index in
348       each partition will be determined as if no index name had been
349       specified in the command. If the ONLY option is specified, no recursion
350       is done, and the index is marked invalid. (ALTER INDEX ... ATTACH
351       PARTITION marks the index valid, once all partitions acquire matching
352       indexes.) Note, however, that any partition that is created in the
353       future using CREATE TABLE ... PARTITION OF will automatically have a
354       matching index, regardless of whether ONLY is specified.
355
356       For index methods that support ordered scans (currently, only B-tree),
357       the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
358       specified to modify the sort ordering of the index. Since an ordered
359       index can be scanned either forward or backward, it is not normally
360       useful to create a single-column DESC index — that sort ordering is
361       already available with a regular index. The value of these options is
362       that multicolumn indexes can be created that match the sort ordering
363       requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
364       y DESC. The NULLS options are useful if you need to support “nulls sort
365       low” behavior, rather than the default “nulls sort high”, in queries
366       that depend on indexes to avoid sorting steps.
367
368       For most index methods, the speed of creating an index is dependent on
369       the setting of maintenance_work_mem. Larger values will reduce the time
370       needed for index creation, so long as you don't make it larger than the
371       amount of memory really available, which would drive the machine into
372       swapping.
373
374       PostgreSQL can build indexes while leveraging multiple CPUs in order to
375       process the table rows faster. This feature is known as parallel index
376       build. For index methods that support building indexes in parallel
377       (currently, only B-tree), maintenance_work_mem specifies the maximum
378       amount of memory that can be used by each index build operation as a
379       whole, regardless of how many worker processes were started. Generally,
380       a cost model automatically determines how many worker processes should
381       be requested, if any.
382
383       Parallel index builds may benefit from increasing maintenance_work_mem
384       where an equivalent serial index build will see little or no benefit.
385       Note that maintenance_work_mem may influence the number of worker
386       processes requested, since parallel workers must have at least a 32MB
387       share of the total maintenance_work_mem budget. There must also be a
388       remaining 32MB share for the leader process. Increasing
389       max_parallel_maintenance_workers may allow more workers to be used,
390       which will reduce the time needed for index creation, so long as the
391       index build is not already I/O bound. Of course, there should also be
392       sufficient CPU capacity that would otherwise lie idle.
393
394       Setting a value for parallel_workers via ALTER TABLE (ALTER_TABLE(7))
395       directly controls how many parallel worker processes will be requested
396       by a CREATE INDEX against the table. This bypasses the cost model
397       completely, and prevents maintenance_work_mem from affecting how many
398       parallel workers are requested. Setting parallel_workers to 0 via ALTER
399       TABLE will disable parallel index builds on the table in all cases.
400
401           Tip
402           You might want to reset parallel_workers after setting it as part
403           of tuning an index build. This avoids inadvertent changes to query
404           plans, since parallel_workers affects all parallel table scans.
405
406       While CREATE INDEX with the CONCURRENTLY option supports parallel
407       builds without special restrictions, only the first table scan is
408       actually performed in parallel.
409
410       Use DROP INDEX (DROP_INDEX(7)) to remove an index.
411
412       Prior releases of PostgreSQL also had an R-tree index method. This
413       method has been removed because it had no significant advantages over
414       the GiST method. If USING rtree is specified, CREATE INDEX will
415       interpret it as USING gist, to simplify conversion of old databases to
416       GiST.
417

EXAMPLES

419       To create a unique B-tree index on the column title in the table films:
420
421           CREATE UNIQUE INDEX title_idx ON films (title);
422
423       To create a unique B-tree index on the column title with included
424       columns director and rating in the table films:
425
426           CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
427
428       To create an index on the expression lower(title), allowing efficient
429       case-insensitive searches:
430
431           CREATE INDEX ON films ((lower(title)));
432
433       (In this example we have chosen to omit the index name, so the system
434       will choose a name, typically films_lower_idx.)
435
436       To create an index with non-default collation:
437
438           CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
439
440       To create an index with non-default sort ordering of nulls:
441
442           CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
443
444       To create an index with non-default fill factor:
445
446           CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
447
448       To create a GIN index with fast updates disabled:
449
450           CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
451
452       To create an index on the column code in the table films and have the
453       index reside in the tablespace indexspace:
454
455           CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
456
457       To create a GiST index on a point attribute so that we can efficiently
458       use box operators on the result of the conversion function:
459
460           CREATE INDEX pointloc
461               ON points USING gist (box(location,location));
462           SELECT * FROM points
463               WHERE box(location,location) && '(0,0),(1,1)'::box;
464
465       To create an index without locking out writes to the table:
466
467           CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
468

COMPATIBILITY

470       CREATE INDEX is a PostgreSQL language extension. There are no
471       provisions for indexes in the SQL standard.
472

SEE ALSO

474       ALTER INDEX (ALTER_INDEX(7)), DROP INDEX (DROP_INDEX(7))
475
476
477
478PostgreSQL 11.3                      2019                      CREATE INDEX(7)
Impressum