1CREATE INDEX(7) PostgreSQL 9.2.24 Documentation CREATE INDEX(7)
2
3
4
6 CREATE_INDEX - define a new index
7
9 CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ name ] ON table_name [ USING method ]
10 ( { column_name | ( expression ) } [ COLLATE collation ] [ opclass ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
11 [ WITH ( storage_parameter = value [, ... ] ) ]
12 [ TABLESPACE tablespace_name ]
13 [ WHERE predicate ]
14
16 CREATE INDEX constructs an index on the specified column(s) of the
17 specified table. Indexes are primarily used to enhance database
18 performance (though inappropriate use can result in slower
19 performance).
20
21 The key field(s) for the index are specified as column names, or
22 alternatively as expressions written in parentheses. Multiple fields
23 can be specified if the index method supports multicolumn indexes.
24
25 An index field can be an expression computed from the values of one or
26 more columns of the table row. This feature can be used to obtain fast
27 access to data based on some transformation of the basic data. For
28 example, an index computed on upper(col) would allow the clause WHERE
29 upper(col) = 'JIM' to use an index.
30
31 PostgreSQL provides the index methods B-tree, hash, GiST, SP-GiST, and
32 GIN. Users can also define their own index methods, but that is fairly
33 complicated.
34
35 When the WHERE clause is present, a partial index is created. A partial
36 index is an index that contains entries for only a portion of a table,
37 usually a portion that is more useful for indexing than the rest of the
38 table. For example, if you have a table that contains both billed and
39 unbilled orders where the unbilled orders take up a small fraction of
40 the total table and yet that is an often used section, you can improve
41 performance by creating an index on just that portion. Another possible
42 application is to use WHERE with UNIQUE to enforce uniqueness over a
43 subset of a table. See Section 11.8, “Partial Indexes”, in the
44 documentation 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 CONCURRENTLY
68 When this option is used, PostgreSQL will build the index without
69 taking any locks that prevent concurrent inserts, updates, or
70 deletes on the table; whereas a standard index build locks out
71 writes (but not reads) on the table until it's done. There are
72 several caveats to be aware of when using this option — see
73 Building Indexes Concurrently.
74
75 name
76 The name of the index to be created. No schema name can be included
77 here; the index is always created in the same schema as its parent
78 table. If the name is omitted, PostgreSQL chooses a suitable name
79 based on the parent table's name and the indexed column name(s).
80
81 table_name
82 The name (possibly schema-qualified) of the table to be indexed.
83
84 method
85 The name of the index method to be used. Choices are btree, hash,
86 gist, spgist and gin. The default method is btree.
87
88 column_name
89 The name of a column of the table.
90
91 expression
92 An expression based on one or more columns of the table. The
93 expression usually must be written with surrounding parentheses, as
94 shown in the syntax. However, the parentheses can be omitted if the
95 expression has the form of a function call.
96
97 collation
98 The name of the collation to use for the index. By default, the
99 index uses the collation declared for the column to be indexed or
100 the result collation of the expression to be indexed. Indexes with
101 non-default collations can be useful for queries that involve
102 expressions using non-default collations.
103
104 opclass
105 The name of an operator class. See below for details.
106
107 ASC
108 Specifies ascending sort order (which is the default).
109
110 DESC
111 Specifies descending sort order.
112
113 NULLS FIRST
114 Specifies that nulls sort before non-nulls. This is the default
115 when DESC is specified.
116
117 NULLS LAST
118 Specifies that nulls sort after non-nulls. This is the default when
119 DESC is not specified.
120
121 storage_parameter
122 The name of an index-method-specific storage parameter. See Index
123 Storage Parameters for details.
124
125 tablespace_name
126 The tablespace in which to create the index. If not specified,
127 default_tablespace is consulted, or temp_tablespaces for indexes on
128 temporary tables.
129
130 predicate
131 The constraint expression for a partial index.
132
133 Index Storage Parameters
134 The optional WITH clause specifies storage parameters for the index.
135 Each index method has its own set of allowed storage parameters. The
136 B-tree, hash, GiST and SP-GiST index methods all accept this parameter:
137
138 FILLFACTOR
139 The fillfactor for an index is a percentage that determines how
140 full the index method will try to pack index pages. For B-trees,
141 leaf pages are filled to this percentage during initial index
142 build, and also when extending the index at the right (adding new
143 largest key values). If pages subsequently become completely full,
144 they will be split, leading to gradual degradation in the index's
145 efficiency. B-trees use a default fillfactor of 90, but any integer
146 value from 10 to 100 can be selected. If the table is static then
147 fillfactor 100 is best to minimize the index's physical size, but
148 for heavily updated tables a smaller fillfactor is better to
149 minimize the need for page splits. The other index methods use
150 fillfactor in different but roughly analogous ways; the default
151 fillfactor varies between methods.
152
153 GiST indexes additionally accept this parameter:
154
155 BUFFERING
156 Determines whether the buffering build technique described in
157 Section 53.3.1, “GiST buffering build”, in the documentation is
158 used to build the index. With OFF it is disabled, with ON it is
159 enabled, and with AUTO it is initially disabled, but turned on
160 on-the-fly once the index size reaches effective_cache_size. The
161 default is AUTO.
162
163 GIN indexes accept a different parameter:
164
165 FASTUPDATE
166 This setting controls usage of the fast update technique described
167 in Section 55.3.1, “GIN Fast Update Technique”, in the
168 documentation. It is a Boolean parameter: ON enables fast update,
169 OFF disables it. (Alternative spellings of ON and OFF are allowed
170 as described in Section 18.1, “Setting Parameters”, in the
171 documentation.) The default is ON.
172
173 Note
174 Turning FASTUPDATE off via ALTER INDEX prevents future
175 insertions from going into the list of pending index entries,
176 but does not in itself flush previous entries. You might want
177 to VACUUM the table afterward to ensure the pending list is
178 emptied.
179
180 Building Indexes Concurrently
181 Creating an index can interfere with regular operation of a database.
182 Normally PostgreSQL locks the table to be indexed against writes and
183 performs the entire index build with a single scan of the table. Other
184 transactions can still read the table, but if they try to insert,
185 update, or delete rows in the table they will block until the index
186 build is finished. This could have a severe effect if the system is a
187 live production database. Very large tables can take many hours to be
188 indexed, and even for smaller tables, an index build can lock out
189 writers for periods that are unacceptably long for a production system.
190
191 PostgreSQL supports building indexes without locking out writes. This
192 method is invoked by specifying the CONCURRENTLY option of CREATE
193 INDEX. When this option is used, PostgreSQL must perform two scans of
194 the table, and in addition it must wait for all existing transactions
195 that could potentially modify or use the index to terminate. Thus this
196 method requires more total work than a standard index build and takes
197 significantly longer to complete. However, since it allows normal
198 operations to continue while the index is built, this method is useful
199 for adding new indexes in a production environment. Of course, the
200 extra CPU and I/O load imposed by the index creation might slow other
201 operations.
202
203 In a concurrent index build, the index is actually entered into the
204 system catalogs in one transaction, then two table scans occur in two
205 more transactions. Before each table scan, the index build must wait
206 for existing transactions that have modified the table to terminate.
207 After the second scan, the index build must wait for any transactions
208 that have a snapshot (see Chapter 13, Concurrency Control, in the
209 documentation) predating the second scan to terminate. Then finally the
210 index can be marked ready for use, and the CREATE INDEX command
211 terminates. Even then, however, the index may not be immediately usable
212 for queries: in the worst case, it cannot be used as long as
213 transactions exist that predate the start of the index build.
214
215 If a problem arises while scanning the table, such as a uniqueness
216 violation in a unique index, the CREATE INDEX command will fail but
217 leave behind an “invalid” index. This index will be ignored for
218 querying purposes because it might be incomplete; however it will still
219 consume update overhead. The psql\d command will report such an index
220 as INVALID:
221
222 postgres=# \d tab
223 Table "public.tab"
224 Column | Type | Modifiers
225 --------+---------+-----------
226 col | integer |
227 Indexes:
228 "idx" btree (col) INVALID
229
230 The recommended recovery method in such cases is to drop the index and
231 try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
232 to rebuild the index with REINDEX. However, since REINDEX does not
233 support concurrent builds, this option is unlikely to seem attractive.)
234
235 Another caveat when building a unique index concurrently is that the
236 uniqueness constraint is already being enforced against other
237 transactions when the second table scan begins. This means that
238 constraint violations could be reported in other queries prior to the
239 index becoming available for use, or even in cases where the index
240 build eventually fails. Also, if a failure does occur in the second
241 scan, the “invalid” index continues to enforce its uniqueness
242 constraint afterwards.
243
244 Concurrent builds of expression indexes and partial indexes are
245 supported. Errors occurring in the evaluation of these expressions
246 could cause behavior similar to that described above for unique
247 constraint violations.
248
249 Regular index builds permit other regular index builds on the same
250 table to occur in parallel, but only one concurrent index build can
251 occur on a table at a time. In both cases, no other types of schema
252 modification on the table are allowed meanwhile. Another difference is
253 that a regular CREATE INDEX command can be performed within a
254 transaction block, but CREATE INDEX CONCURRENTLY cannot.
255
257 See Chapter 11, Indexes, in the documentation for information about
258 when indexes can be used, when they are not used, and in which
259 particular situations they can be useful.
260
261 Caution
262 Hash index operations are not presently WAL-logged, so hash indexes
263 might need to be rebuilt with REINDEX after a database crash if
264 there were unwritten changes. Also, changes to hash indexes are not
265 replicated over streaming or file-based replication after the
266 initial base backup, so they give wrong answers to queries that
267 subsequently use them. For these reasons, hash index use is
268 presently discouraged.
269
270 Currently, only the B-tree, GiST and GIN index methods support
271 multicolumn indexes. Up to 32 fields can be specified by default. (This
272 limit can be altered when building PostgreSQL.) Only B-tree currently
273 supports unique indexes.
274
275 An operator class can be specified for each column of an index. The
276 operator class identifies the operators to be used by the index for
277 that column. For example, a B-tree index on four-byte integers would
278 use the int4_ops class; this operator class includes comparison
279 functions for four-byte integers. In practice the default operator
280 class for the column's data type is usually sufficient. The main point
281 of having operator classes is that for some data types, there could be
282 more than one meaningful ordering. For example, we might want to sort a
283 complex-number data type either by absolute value or by real part. We
284 could do this by defining two operator classes for the data type and
285 then selecting the proper class when making an index. More information
286 about operator classes is in Section 11.9, “Operator Classes and
287 Operator Families”, in the documentation and in Section 35.14,
288 “Interfacing Extensions To Indexes”, in the documentation.
289
290 For index methods that support ordered scans (currently, only B-tree),
291 the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
292 specified to modify the sort ordering of the index. Since an ordered
293 index can be scanned either forward or backward, it is not normally
294 useful to create a single-column DESC index — that sort ordering is
295 already available with a regular index. The value of these options is
296 that multicolumn indexes can be created that match the sort ordering
297 requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
298 y DESC. The NULLS options are useful if you need to support “nulls sort
299 low” behavior, rather than the default “nulls sort high”, in queries
300 that depend on indexes to avoid sorting steps.
301
302 For most index methods, the speed of creating an index is dependent on
303 the setting of maintenance_work_mem. Larger values will reduce the time
304 needed for index creation, so long as you don't make it larger than the
305 amount of memory really available, which would drive the machine into
306 swapping.
307
308 Use DROP INDEX (DROP_INDEX(7)) to remove an index.
309
310 Prior releases of PostgreSQL also had an R-tree index method. This
311 method has been removed because it had no significant advantages over
312 the GiST method. If USING rtree is specified, CREATE INDEX will
313 interpret it as USING gist, to simplify conversion of old databases to
314 GiST.
315
317 To create a B-tree index on the column title in the table films:
318
319 CREATE UNIQUE INDEX title_idx ON films (title);
320
321 To create an index on the expression lower(title), allowing efficient
322 case-insensitive searches:
323
324 CREATE INDEX ON films ((lower(title)));
325
326 (In this example we have chosen to omit the index name, so the system
327 will choose a name, typically films_lower_idx.)
328
329 To create an index with non-default collation:
330
331 CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
332
333 To create an index with non-default sort ordering of nulls:
334
335 CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
336
337 To create an index with non-default fill factor:
338
339 CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
340
341 To create a GIN index with fast updates disabled:
342
343 CREATE INDEX gin_idx ON documents_table USING gin (locations) WITH (fastupdate = off);
344
345 To create an index on the column code in the table films and have the
346 index reside in the tablespace indexspace:
347
348 CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
349
350 To create a GiST index on a point attribute so that we can efficiently
351 use box operators on the result of the conversion function:
352
353 CREATE INDEX pointloc
354 ON points USING gist (box(location,location));
355 SELECT * FROM points
356 WHERE box(location,location) && '(0,0),(1,1)'::box;
357
358 To create an index without locking out writes to the table:
359
360 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
361
363 CREATE INDEX is a PostgreSQL language extension. There are no
364 provisions for indexes in the SQL standard.
365
367 ALTER INDEX (ALTER_INDEX(7)), DROP INDEX (DROP_INDEX(7))
368
369
370
371PostgreSQL 9.2.24 2017-11-06 CREATE INDEX(7)