1CREATE INDEX(7) SQL Commands CREATE INDEX(7)
2
3
4
6 CREATE INDEX - define a new index
7
8
10 CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] name ON table [ USING method ]
11 ( { column | ( expression ) } [ opclass ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
12 [ WITH ( storage_parameter = value [, ... ] ) ]
13 [ TABLESPACE tablespace ]
14 [ WHERE predicate ]
15
16
18 CREATE INDEX constructs an index named name on the specified table.
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 alter‐
23 natively as expressions written in parentheses. Multiple fields can be
24 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, and GIN.
33 Users can also define their own index methods, but that is fairly com‐
34 plicated.
35
36 When the WHERE clause is present, a partial index is created. A par‐
37 tial index is an index that contains entries for only a portion of a
38 table, usually a portion that is more useful for indexing than the rest
39 of the table. For example, if you have a table that contains both
40 billed and unbilled orders where the unbilled orders take up a small
41 fraction of the total table and yet that is an often used section, you
42 can improve performance by creating an index on just that portion.
43 Another possible application is to use WHERE with UNIQUE to enforce
44 uniqueness over a subset of a table. See in the documentation for more
45 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 argu‐
55 ments and never on any outside influence (such as the contents of
56 another table or the current time). This restriction ensures that the
57 behavior of the index is well-defined. To use a user-defined function
58 in an index expression or WHERE clause, remember to mark the function
59 immutable when you create it.
60
62 UNIQUE Causes the system to check for duplicate values in the table
63 when the index is created (if data already exist) and each time
64 data is added. Attempts to insert or update data which would
65 result in duplicate entries will generate an error.
66
67 CONCURRENTLY
68 When this option is used, PostgreSQL will build the index with‐
69 out taking any locks that prevent concurrent inserts, updates,
70 or deletes on the table; whereas a standard index build locks
71 out writes (but not reads) on the table until it's done. There
72 are several caveats to be aware of when using this option — see
73 Building Indexes Concurrently [create_index(7)].
74
75 name The name of the index to be created. No schema name can be
76 included here; the index is always created in the same schema as
77 its parent table.
78
79 table The name (possibly schema-qualified) of the table to be indexed.
80
81 method The name of the index method to be used. Choices are btree,
82 hash, gist, and gin. The default method is btree.
83
84 column The name of a column of the table.
85
86 expression
87 An expression based on one or more columns of the table. The
88 expression usually must be written with surrounding parentheses,
89 as shown in the syntax. However, the parentheses can be omitted
90 if the expression has the form of a function call.
91
92 opclass
93 The name of an operator class. See below for details.
94
95 ASC Specifies ascending sort order (which is the default).
96
97 DESC Specifies descending sort order.
98
99 NULLS FIRST
100 Specifies that nulls sort before non-nulls. This is the default
101 when DESC is specified.
102
103 NULLS LAST
104 Specifies that nulls sort after non-nulls. This is the default
105 when DESC is not specified.
106
107 storage_parameter
108 The name of an index-method-specific storage parameter. See
109 Index Storage Parameters [create_index(7)] for details.
110
111 tablespace
112 The tablespace in which to create the index. If not specified,
113 default_tablespace is consulted, or temp_tablespaces for indexes
114 on temporary tables.
115
116 predicate
117 The constraint expression for a partial index.
118
119 INDEX STORAGE PARAMETERS
120 The optional WITH clause specifies storage parameters for the index.
121 Each index method has its own set of allowed storage parameters. The B-
122 tree, hash and GiST index methods all accept a single parameter:
123
124 FILLFACTOR
125 The fillfactor for an index is a percentage that determines how
126 full the index method will try to pack index pages. For B-trees,
127 leaf pages are filled to this percentage during initial index
128 build, and also when extending the index at the right (adding
129 new largest key values). If pages subsequently become com‐
130 pletely full, they will be split, leading to gradual degradation
131 in the index's efficiency. B-trees use a default fillfactor of
132 90, but any integer value from 10 to 100 can be selected. If
133 the table is static then fillfactor 100 is best to minimize the
134 index's physical size, but for heavily updated tables a smaller
135 fillfactor is better to minimize the need for page splits. The
136 other index methods use fillfactor in different but roughly
137 analogous ways; the default fillfactor varies between methods.
138
139 GIN indexes accept a different parameter:
140
141 FASTUPDATE
142 This setting controls usage of the fast update technique
143 described in in the documentation. It is a Boolean parameter: ON
144 enables fast update, OFF disables it. (Alternative spellings of
145 ON and OFF are allowed as described in in the documentation.)
146 The default is ON.
147
148 Note: Turning FASTUPDATE off via ALTER INDEX prevents future
149 insertions from going into the list of pending index entries,
150 but does not in itself flush previous entries. You might want to
151 VACUUM the table afterward to ensure the pending list is emp‐
152 tied.
153
154
155 BUILDING INDEXES CONCURRENTLY
156 Creating an index can interfere with regular operation of a database.
157 Normally PostgreSQL locks the table to be indexed against writes and
158 performs the entire index build with a single scan of the table. Other
159 transactions can still read the table, but if they try to insert,
160 update, or delete rows in the table they will block until the index
161 build is finished. This could have a severe effect if the system is a
162 live production database. Very large tables can take many hours to be
163 indexed, and even for smaller tables, an index build can lock out writ‐
164 ers for periods that are unacceptably long for a production system.
165
166 PostgreSQL supports building indexes without locking out writes. This
167 method is invoked by specifying the CONCURRENTLY option of CREATE
168 INDEX. When this option is used, PostgreSQL must perform two scans of
169 the table, and in addition it must wait for all existing transactions
170 that could potentially use the index to terminate. Thus this method
171 requires more total work than a standard index build and takes signifi‐
172 cantly longer to complete. However, since it allows normal operations
173 to continue while the index is built, this method is useful for adding
174 new indexes in a production environment. Of course, the extra CPU and
175 I/O load imposed by the index creation might slow other operations.
176
177 In a concurrent index build, the index is actually entered into the
178 system catalogs in one transaction, then the two table scans occur in a
179 second and third transaction. If a problem arises while scanning the
180 table, such as a uniqueness violation in a unique index, the CREATE
181 INDEX command will fail but leave behind an ``invalid'' index. This
182 index will be ignored for querying purposes because it might be incom‐
183 plete; however it will still consume update overhead. The psql \d com‐
184 mand will report such an index as INVALID:
185
186 postgres=# \d tab
187 Table "public.tab"
188 Column | Type | Modifiers
189 --------+---------+-----------
190 col | integer |
191 Indexes:
192 "idx" btree (col) INVALID
193
194 The recommended recovery method in such cases is to drop the index and
195 try again to perform CREATE INDEX CONCURRENTLY. (Another possibility is
196 to rebuild the index with REINDEX. However, since REINDEX does not sup‐
197 port concurrent builds, this option is unlikely to seem attractive.)
198
199 Another caveat when building a unique index concurrently is that the
200 uniqueness constraint is already being enforced against other transac‐
201 tions when the second table scan begins. This means that constraint
202 violations could be reported in other queries prior to the index becom‐
203 ing available for use, or even in cases where the index build eventu‐
204 ally fails. Also, if a failure does occur in the second scan, the
205 ``invalid'' index continues to enforce its uniqueness constraint after‐
206 wards.
207
208 Concurrent builds of expression indexes and partial indexes are sup‐
209 ported. Errors occurring in the evaluation of these expressions could
210 cause behavior similar to that described above for unique constraint
211 violations.
212
213 Regular index builds permit other regular index builds on the same ta‐
214 ble to occur in parallel, but only one concurrent index build can occur
215 on a table at a time. In both cases, no other types of schema modifica‐
216 tion on the table are allowed meanwhile. Another difference is that a
217 regular CREATE INDEX command can be performed within a transaction
218 block, but CREATE INDEX CONCURRENTLY cannot.
219
221 See in the documentation for information about when indexes can be
222 used, when they are not used, and in which particular situations they
223 can be useful.
224
225 Currently, only the B-tree, GiST and GIN index methods support multi‐
226 column indexes. Up to 32 fields can be specified by default. (This
227 limit can be altered when building PostgreSQL.) Only B-tree currently
228 supports unique indexes.
229
230 An operator class can be specified for each column of an index. The
231 operator class identifies the operators to be used by the index for
232 that column. For example, a B-tree index on four-byte integers would
233 use the int4_ops class; this operator class includes comparison func‐
234 tions for four-byte integers. In practice the default operator class
235 for the column's data type is usually sufficient. The main point of
236 having operator classes is that for some data types, there could be
237 more than one meaningful ordering. For example, we might want to sort a
238 complex-number data type either by absolute value or by real part. We
239 could do this by defining two operator classes for the data type and
240 then selecting the proper class when making an index. More information
241 about operator classes is in in the documentation and in in the docu‐
242 mentation.
243
244 For index methods that support ordered scans (currently, only B-tree),
245 the optional clauses ASC, DESC, NULLS FIRST, and/or NULLS LAST can be
246 specified to modify the sort ordering of the index. Since an ordered
247 index can be scanned either forward or backward, it is not normally
248 useful to create a single-column DESC index — that sort ordering is
249 already available with a regular index. The value of these options is
250 that multicolumn indexes can be created that match the sort ordering
251 requested by a mixed-ordering query, such as SELECT ... ORDER BY x ASC,
252 y DESC. The NULLS options are useful if you need to support ``nulls
253 sort low'' behavior, rather than the default ``nulls sort high'', in
254 queries that depend on indexes to avoid sorting steps.
255
256 For most index methods, the speed of creating an index is dependent on
257 the setting of maintenance_work_mem. Larger values will reduce the
258 time needed for index creation, so long as you don't make it larger
259 than the amount of memory really available, which would drive the
260 machine into swapping. For hash indexes, the value of effec‐
261 tive_cache_size is also relevant to index creation time: PostgreSQL
262 will use one of two different hash index creation methods depending on
263 whether the estimated index size is more or less than effec‐
264 tive_cache_size. For best results, make sure that this parameter is
265 also set to something reflective of available memory, and be careful
266 that the sum of maintenance_work_mem and effective_cache_size is less
267 than the machine's RAM less whatever space is needed by other programs.
268
269 Use DROP INDEX [drop_index(7)] to remove an index.
270
271 Prior releases of PostgreSQL also had an R-tree index method. This
272 method has been removed because it had no significant advantages over
273 the GiST method. If USING rtree is specified, CREATE INDEX will inter‐
274 pret it as USING gist, to simplify conversion of old databases to GiST.
275
277 To create a B-tree index on the column title in the table films:
278
279 CREATE UNIQUE INDEX title_idx ON films (title);
280
281
282 To create an index on the expression lower(title), allowing efficient
283 case-insensitive searches:
284
285 CREATE INDEX lower_title_idx ON films ((lower(title)));
286
287
288 To create an index with non-default sort ordering of nulls:
289
290 CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
291
292
293 To create an index with non-default fill factor:
294
295 CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
296
297
298 To create a GIN index with fast updates disabled:
299
300 CREATE INDEX gin_idx ON documents_table USING gin (locations) WITH (fastupdate = off);
301
302
303 To create an index on the column code in the table films and have the
304 index reside in the tablespace indexspace:
305
306 CREATE INDEX code_idx ON films(code) TABLESPACE indexspace;
307
308
309 To create a GiST index on a point attribute so that we can efficiently
310 use box operators on the result of the conversion function:
311
312 CREATE INDEX pointloc
313 ON points USING gist (box(location,location));
314 SELECT * FROM points
315 WHERE box(location,location) && '(0,0),(1,1)'::box;
316
317
318
319 To create an index without locking out writes to the table:
320
321 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
322
323
325 CREATE INDEX is a PostgreSQL language extension. There are no provi‐
326 sions for indexes in the SQL standard.
327
329 ALTER INDEX [alter_index(7)], DROP INDEX [drop_index(7)]
330
331
332
333SQL - Language Statements 2011-09-22 CREATE INDEX(7)