1CREATE INDEX(7) PostgreSQL 12.6 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 ] [ 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.
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
106 Columns listed in the INCLUDE clause don't need appropriate
107 operator classes; the clause can include columns whose data types
108 don't have operator classes defined for a given access method.
109
110 Expressions are not supported as included columns since they cannot
111 be used in index-only scans.
112
113 Currently, the B-tree and the GiST index access methods support
114 this feature. In B-tree and the GiST indexes, the values of columns
115 listed in the INCLUDE clause are included in leaf tuples which
116 correspond to heap tuples, but are not included in upper-level
117 index entries used for tree navigation.
118
119 name
120 The name of the index to be created. No schema name can be included
121 here; the index is always created in the same schema as its parent
122 table. If the name is omitted, PostgreSQL chooses a suitable name
123 based on the parent table's name and the indexed column name(s).
124
125 ONLY
126 Indicates not to recurse creating indexes on partitions, if the
127 table is partitioned. The default is to recurse.
128
129 table_name
130 The name (possibly schema-qualified) of the table to be indexed.
131
132 method
133 The name of the index method to be used. Choices are btree, hash,
134 gist, spgist, gin, and brin. The default method is btree.
135
136 column_name
137 The name of a column of the table.
138
139 expression
140 An expression based on one or more columns of the table. The
141 expression usually must be written with surrounding parentheses, as
142 shown in the syntax. However, the parentheses can be omitted if the
143 expression has the form of a function call.
144
145 collation
146 The name of the collation to use for the index. By default, the
147 index uses the collation declared for the column to be indexed or
148 the result collation of the expression to be indexed. Indexes with
149 non-default collations can be useful for queries that involve
150 expressions using non-default collations.
151
152 opclass
153 The name of an operator class. See below for details.
154
155 ASC
156 Specifies ascending sort order (which is the default).
157
158 DESC
159 Specifies descending sort order.
160
161 NULLS FIRST
162 Specifies that nulls sort before non-nulls. This is the default
163 when DESC is specified.
164
165 NULLS LAST
166 Specifies that nulls sort after non-nulls. This is the default when
167 DESC is not specified.
168
169 storage_parameter
170 The name of an index-method-specific storage parameter. See Index
171 Storage Parameters for details.
172
173 tablespace_name
174 The tablespace in which to create the index. If not specified,
175 default_tablespace is consulted, or temp_tablespaces for indexes on
176 temporary tables.
177
178 predicate
179 The constraint expression for a partial index.
180
181 Index Storage Parameters
182 The optional WITH clause specifies storage parameters for the index.
183 Each index method has its own set of allowed storage parameters. The
184 B-tree, hash, GiST and SP-GiST index methods all accept this parameter:
185
186 fillfactor
187 The fillfactor for an index is a percentage that determines how
188 full the index method will try to pack index pages. For B-trees,
189 leaf pages are filled to this percentage during initial index
190 build, and also when extending the index at the right (adding new
191 largest key values). If pages subsequently become completely full,
192 they will be split, leading to gradual degradation in the index's
193 efficiency. B-trees use a default fillfactor of 90, but any integer
194 value from 10 to 100 can be selected. If the table is static then
195 fillfactor 100 is best to minimize the index's physical size, but
196 for heavily updated tables a smaller fillfactor is better to
197 minimize the need for page splits. The other index methods use
198 fillfactor in different but roughly analogous ways; the default
199 fillfactor varies between methods.
200
201 B-tree indexes additionally accept this parameter:
202
203 vacuum_cleanup_index_scale_factor
204 Per-index value for vacuum_cleanup_index_scale_factor.
205
206 GiST indexes additionally accept this parameter:
207
208 buffering
209 Determines whether the buffering build technique described in
210 Section 64.4.1 is used to build the index. With OFF it is disabled,
211 with ON it is enabled, and with AUTO it is initially disabled, but
212 turned on on-the-fly once the index size reaches
213 effective_cache_size. The default is AUTO.
214
215 GIN indexes accept different parameters:
216
217 fastupdate
218 This setting controls usage of the fast update technique described
219 in Section 66.4.1. It is a Boolean parameter: ON enables fast
220 update, OFF disables it. (Alternative spellings of ON and OFF are
221 allowed as described in Section 19.1.) The default is ON.
222
223 Note
224 Turning fastupdate off via ALTER INDEX prevents future
225 insertions from going into the list of pending index entries,
226 but does not in itself flush previous entries. You might want
227 to VACUUM the table or call gin_clean_pending_list function
228 afterward to ensure the pending list is emptied.
229
230 gin_pending_list_limit
231 Custom gin_pending_list_limit parameter. This value is specified in
232 kilobytes.
233
234 BRIN indexes accept different parameters:
235
236 pages_per_range
237 Defines the number of table blocks that make up one block range for
238 each entry of a BRIN index (see Section 67.1 for more details). The
239 default is 128.
240
241 autosummarize
242 Defines whether a summarization run is invoked for the previous
243 page range whenever an insertion is detected on the next one.
244
245 Building Indexes Concurrently
246 Creating an index can interfere with regular operation of a database.
247 Normally PostgreSQL locks the table to be indexed against writes and
248 performs the entire index build with a single scan of the table. Other
249 transactions can still read the table, but if they try to insert,
250 update, or delete rows in the table they will block until the index
251 build is finished. This could have a severe effect if the system is a
252 live production database. Very large tables can take many hours to be
253 indexed, and even for smaller tables, an index build can lock out
254 writers for periods that are unacceptably long for a production system.
255
256 PostgreSQL supports building indexes without locking out writes. This
257 method is invoked by specifying the CONCURRENTLY option of CREATE
258 INDEX. When this option is used, PostgreSQL must perform two scans of
259 the table, and in addition it must wait for all existing transactions
260 that could potentially modify or use the index to terminate. Thus this
261 method requires more total work than a standard index build and takes
262 significantly longer to complete. However, since it allows normal
263 operations to continue while the index is built, this method is useful
264 for adding new indexes in a production environment. Of course, the
265 extra CPU and I/O load imposed by the index creation might slow other
266 operations.
267
268 In a concurrent index build, the index is actually entered into the
269 system catalogs in one transaction, then two table scans occur in two
270 more transactions. Before each table scan, the index build must wait
271 for existing transactions that have modified the table to terminate.
272 After the second scan, the index build must wait for any transactions
273 that have a snapshot (see Chapter 13) predating the second scan to
274 terminate, including transactions used by any phase of concurrent index
275 builds on other tables. Then finally the index can be marked ready for
276 use, and the CREATE INDEX command terminates. Even then, however, the
277 index may not be immediately usable for queries: in the worst case, it
278 cannot be used as long as transactions exist that predate the start of
279 the index build.
280
281 If a problem arises while scanning the table, such as a deadlock or a
282 uniqueness violation in a unique index, the CREATE INDEX command will
283 fail but leave behind an “invalid” index. This index will be ignored
284 for querying purposes because it might be incomplete; however it will
285 still consume update overhead. The psql \d command will report such an
286 index as INVALID:
287
288 postgres=# \d tab
289 Table "public.tab"
290 Column | Type | Collation | Nullable | Default
291 --------+---------+-----------+----------+---------
292 col | integer | | |
293 Indexes:
294 "idx" btree (col) INVALID
295
296 The recommended recovery method in such cases is to drop the index and
297 try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
298 to rebuild the index with REINDEX INDEX CONCURRENTLY).
299
300 Another caveat when building a unique index concurrently is that the
301 uniqueness constraint is already being enforced against other
302 transactions when the second table scan begins. This means that
303 constraint violations could be reported in other queries prior to the
304 index becoming available for use, or even in cases where the index
305 build eventually fails. Also, if a failure does occur in the second
306 scan, the “invalid” index continues to enforce its uniqueness
307 constraint afterwards.
308
309 Concurrent builds of expression indexes and partial indexes are
310 supported. Errors occurring in the evaluation of these expressions
311 could cause behavior similar to that described above for unique
312 constraint violations.
313
314 Regular index builds permit other regular index builds on the same
315 table to occur simultaneously, but only one concurrent index build can
316 occur on a table at a time. In either case, schema modification of the
317 table is not allowed while the index is being built. Another difference
318 is that a regular CREATE INDEX command can be performed within a
319 transaction block, but CREATE INDEX CONCURRENTLY cannot.
320
321 Concurrent builds for indexes on partitioned tables are currently not
322 supported. However, you may concurrently build the index on each
323 partition individually and then finally create the partitioned index
324 non-concurrently in order to reduce the time where writes to the
325 partitioned table will be locked out. In this case, building the
326 partitioned index is a metadata only operation.
327
329 See Chapter 11 for information about when indexes can be used, when
330 they are not used, and in which particular situations they can be
331 useful.
332
333 Currently, only the B-tree, GiST, GIN, and BRIN index methods support
334 multicolumn indexes. Up to 32 fields can be specified by default. (This
335 limit can be altered when building PostgreSQL.) Only B-tree currently
336 supports unique indexes.
337
338 An operator class can be specified for each column of an index. The
339 operator class identifies the operators to be used by the index for
340 that column. For example, a B-tree index on four-byte integers would
341 use the int4_ops class; this operator class includes comparison
342 functions for four-byte integers. In practice the default operator
343 class for the column's data type is usually sufficient. The main point
344 of having operator classes is that for some data types, there could be
345 more than one meaningful ordering. For example, we might want to sort a
346 complex-number data type either by absolute value or by real part. We
347 could do this by defining two operator classes for the data type and
348 then selecting the proper class when creating an index. More
349 information about operator classes is in Section 11.10 and in
350 Section 37.16.
351
352 When CREATE INDEX is invoked on a partitioned table, the default
353 behavior is to recurse to all partitions to ensure they all have
354 matching indexes. Each partition is first checked to determine whether
355 an equivalent index already exists, and if so, that index will become
356 attached as a partition index to the index being created, which will
357 become its parent index. If no matching index exists, a new index will
358 be created and automatically attached; the name of the new index in
359 each partition will be determined as if no index name had been
360 specified in the command. If the ONLY option is specified, no recursion
361 is done, and the index is marked invalid. (ALTER INDEX ... ATTACH
362 PARTITION marks the index valid, once all partitions acquire matching
363 indexes.) Note, however, that any partition that is created in the
364 future using CREATE TABLE ... PARTITION OF will automatically have a
365 matching index, regardless of whether ONLY is specified.
366
367 For index methods that support ordered scans (currently, only B-tree),
368 the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
369 specified to modify the sort ordering of the index. Since an ordered
370 index can be scanned either forward or backward, it is not normally
371 useful to create a single-column DESC index — that sort ordering is
372 already available with a regular index. The value of these options is
373 that multicolumn indexes can be created that match the sort ordering
374 requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
375 y DESC. The NULLS options are useful if you need to support “nulls sort
376 low” behavior, rather than the default “nulls sort high”, in queries
377 that depend on indexes to avoid sorting steps.
378
379 The system regularly collects statistics on all of a table's columns.
380 Newly-created non-expression indexes can immediately use these
381 statistics to determine an index's usefulness. For new expression
382 indexes, it is necessary to run ANALYZE or wait for the autovacuum
383 daemon to analyze the table to generate statistics for these indexes.
384
385 For most index methods, the speed of creating an index is dependent on
386 the setting of maintenance_work_mem. Larger values will reduce the time
387 needed for index creation, so long as you don't make it larger than the
388 amount of memory really available, which would drive the machine into
389 swapping.
390
391 PostgreSQL can build indexes while leveraging multiple CPUs in order to
392 process the table rows faster. This feature is known as parallel index
393 build. For index methods that support building indexes in parallel
394 (currently, only B-tree), maintenance_work_mem specifies the maximum
395 amount of memory that can be used by each index build operation as a
396 whole, regardless of how many worker processes were started. Generally,
397 a cost model automatically determines how many worker processes should
398 be requested, if any.
399
400 Parallel index builds may benefit from increasing maintenance_work_mem
401 where an equivalent serial index build will see little or no benefit.
402 Note that maintenance_work_mem may influence the number of worker
403 processes requested, since parallel workers must have at least a 32MB
404 share of the total maintenance_work_mem budget. There must also be a
405 remaining 32MB share for the leader process. Increasing
406 max_parallel_maintenance_workers may allow more workers to be used,
407 which will reduce the time needed for index creation, so long as the
408 index build is not already I/O bound. Of course, there should also be
409 sufficient CPU capacity that would otherwise lie idle.
410
411 Setting a value for parallel_workers via ALTER TABLE (ALTER_TABLE(7))
412 directly controls how many parallel worker processes will be requested
413 by a CREATE INDEX against the table. This bypasses the cost model
414 completely, and prevents maintenance_work_mem from affecting how many
415 parallel workers are requested. Setting parallel_workers to 0 via ALTER
416 TABLE will disable parallel index builds on the table in all cases.
417
418 Tip
419 You might want to reset parallel_workers after setting it as part
420 of tuning an index build. This avoids inadvertent changes to query
421 plans, since parallel_workers affects all parallel table scans.
422
423 While CREATE INDEX with the CONCURRENTLY option supports parallel
424 builds without special restrictions, only the first table scan is
425 actually performed in parallel.
426
427 Use DROP INDEX (DROP_INDEX(7)) to remove an index.
428
429 Like any long-running transaction, CREATE INDEX on a table can affect
430 which tuples can be removed by concurrent VACUUM on any other table.
431
432 Prior releases of PostgreSQL also had an R-tree index method. This
433 method has been removed because it had no significant advantages over
434 the GiST method. If USING rtree is specified, CREATE INDEX will
435 interpret it as USING gist, to simplify conversion of old databases to
436 GiST.
437
439 To create a unique B-tree index on the column title in the table films:
440
441 CREATE UNIQUE INDEX title_idx ON films (title);
442
443 To create a unique B-tree index on the column title with included
444 columns director and rating in the table films:
445
446 CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
447
448 To create an index on the expression lower(title), allowing efficient
449 case-insensitive searches:
450
451 CREATE INDEX ON films ((lower(title)));
452
453 (In this example we have chosen to omit the index name, so the system
454 will choose a name, typically films_lower_idx.)
455
456 To create an index with non-default collation:
457
458 CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
459
460 To create an index with non-default sort ordering of nulls:
461
462 CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
463
464 To create an index with non-default fill factor:
465
466 CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
467
468 To create a GIN index with fast updates disabled:
469
470 CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
471
472 To create an index on the column code in the table films and have the
473 index reside in the tablespace indexspace:
474
475 CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
476
477 To create a GiST index on a point attribute so that we can efficiently
478 use box operators on the result of the conversion function:
479
480 CREATE INDEX pointloc
481 ON points USING gist (box(location,location));
482 SELECT * FROM points
483 WHERE box(location,location) && '(0,0),(1,1)'::box;
484
485 To create an index without locking out writes to the table:
486
487 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
488
490 CREATE INDEX is a PostgreSQL language extension. There are no
491 provisions for indexes in the SQL standard.
492
494 ALTER INDEX (ALTER_INDEX(7)), DROP INDEX (DROP_INDEX(7)), REINDEX(7)
495
496
497
498PostgreSQL 12.6 2021 CREATE INDEX(7)