1 <?xml version="1.0" encoding="UTF-8" standalone="no"?>
2 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>CREATE INDEX</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets Vsnapshot" /><link rel="prev" href="sql-creategroup.html" title="CREATE GROUP" /><link rel="next" href="sql-createlanguage.html" title="CREATE LANGUAGE" /></head><body id="docContent" class="container-fluid col-10"><div class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">CREATE INDEX</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-creategroup.html" title="CREATE GROUP">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-createlanguage.html" title="CREATE LANGUAGE">Next</a></td></tr></table><hr /></div><div class="refentry" id="SQL-CREATEINDEX"><div class="titlepage"></div><a id="id-1.9.3.69.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">CREATE INDEX</span></h2><p>CREATE INDEX — define a new index</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
3 CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <em class="replaceable"><code>name</code></em> ] ON [ ONLY ] <em class="replaceable"><code>table_name</code></em> [ USING <em class="replaceable"><code>method</code></em> ]
4 ( { <em class="replaceable"><code>column_name</code></em> | ( <em class="replaceable"><code>expression</code></em> ) } [ COLLATE <em class="replaceable"><code>collation</code></em> ] [ <em class="replaceable"><code>opclass</code></em> [ ( <em class="replaceable"><code>opclass_parameter</code></em> = <em class="replaceable"><code>value</code></em> [, ... ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
5 [ INCLUDE ( <em class="replaceable"><code>column_name</code></em> [, ...] ) ]
6 [ NULLS [ NOT ] DISTINCT ]
7 [ WITH ( <em class="replaceable"><code>storage_parameter</code></em> [= <em class="replaceable"><code>value</code></em>] [, ... ] ) ]
8 [ TABLESPACE <em class="replaceable"><code>tablespace_name</code></em> ]
9 [ WHERE <em class="replaceable"><code>predicate</code></em> ]
10 </pre></div><div class="refsect1" id="id-1.9.3.69.5"><h2>Description</h2><p>
11 <code class="command">CREATE INDEX</code> constructs an index on the specified column(s)
12 of the specified relation, which can be a table or a materialized view.
13 Indexes are primarily used to enhance database performance (though
14 inappropriate use can result in slower performance).
16 The key field(s) for the index are specified as column names,
17 or alternatively as expressions written in parentheses.
18 Multiple fields can be specified if the index method supports
21 An index field can be an expression computed from the values of
22 one or more columns of the table row. This feature can be used
23 to obtain fast access to data based on some transformation of
24 the basic data. For example, an index computed on
25 <code class="literal">upper(col)</code> would allow the clause
26 <code class="literal">WHERE upper(col) = 'JIM'</code> to use an index.
28 <span class="productname">PostgreSQL</span> provides the index methods
29 B-tree, hash, GiST, SP-GiST, GIN, and BRIN. Users can also define their own
30 index methods, but that is fairly complicated.
32 When the <code class="literal">WHERE</code> clause is present, a
33 <em class="firstterm">partial index</em> is created.
34 A partial index is an index that contains entries for only a portion of
35 a table, usually a portion that is more useful for indexing than the
36 rest of the table. For example, if you have a table that contains both
37 billed and unbilled orders where the unbilled orders take up a small
38 fraction of the total table and yet that is an often used section, you
39 can improve performance by creating an index on just that portion.
40 Another possible application is to use <code class="literal">WHERE</code> with
41 <code class="literal">UNIQUE</code> to enforce uniqueness over a subset of a
42 table. See <a class="xref" href="indexes-partial.html" title="11.8. Partial Indexes">Section 11.8</a> for more discussion.
44 The expression used in the <code class="literal">WHERE</code> clause can refer
45 only to columns of the underlying table, but it can use all columns,
46 not just the ones being indexed. Presently, subqueries and
47 aggregate expressions are also forbidden in <code class="literal">WHERE</code>.
48 The same restrictions apply to index fields that are expressions.
50 All functions and operators used in an index definition must be
51 <span class="quote">“<span class="quote">immutable</span>”</span>, that is, their results must depend only on
52 their arguments and never on any outside influence (such as
53 the contents of another table or the current time). This restriction
54 ensures that the behavior of the index is well-defined. To use a
55 user-defined function in an index expression or <code class="literal">WHERE</code>
56 clause, remember to mark the function immutable when you create it.
57 </p></div><div class="refsect1" id="id-1.9.3.69.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">UNIQUE</code></span></dt><dd><p>
58 Causes the system to check for
59 duplicate values in the table when the index is created (if data
60 already exist) and each time data is added. Attempts to
61 insert or update data which would result in duplicate entries
62 will generate an error.
64 Additional restrictions apply when unique indexes are applied to
65 partitioned tables; see <a class="xref" href="sql-createtable.html" title="CREATE TABLE"><span class="refentrytitle">CREATE TABLE</span></a>.
66 </p></dd><dt><span class="term"><code class="literal">CONCURRENTLY</code></span></dt><dd><p>
67 When this option is used, <span class="productname">PostgreSQL</span> will build the
68 index without taking any locks that prevent concurrent inserts,
69 updates, or deletes on the table; whereas a standard index build
70 locks out writes (but not reads) on the table until it's done.
71 There are several caveats to be aware of when using this option
72 — see <a class="xref" href="sql-createindex.html#SQL-CREATEINDEX-CONCURRENTLY" title="Building Indexes Concurrently">Building Indexes Concurrently</a> below.
74 For temporary tables, <code class="command">CREATE INDEX</code> is always
75 non-concurrent, as no other session can access them, and
76 non-concurrent index creation is cheaper.
77 </p></dd><dt><span class="term"><code class="literal">IF NOT EXISTS</code></span></dt><dd><p>
78 Do not throw an error if a relation with the same name already exists.
79 A notice is issued in this case. Note that there is no guarantee that
80 the existing index is anything like the one that would have been created.
81 Index name is required when <code class="literal">IF NOT EXISTS</code> is specified.
82 </p></dd><dt><span class="term"><code class="literal">INCLUDE</code></span></dt><dd><p>
83 The optional <code class="literal">INCLUDE</code> clause specifies a
84 list of columns which will be included in the index
85 as <em class="firstterm">non-key</em> columns. A non-key column cannot
86 be used in an index scan search qualification, and it is disregarded
87 for purposes of any uniqueness or exclusion constraint enforced by
88 the index. However, an index-only scan can return the contents of
89 non-key columns without having to visit the index's table, since
90 they are available directly from the index entry. Thus, addition of
91 non-key columns allows index-only scans to be used for queries that
92 otherwise could not use them.
94 It's wise to be conservative about adding non-key columns to an
95 index, especially wide columns. If an index tuple exceeds the
96 maximum size allowed for the index type, data insertion will fail.
97 In any case, non-key columns duplicate data from the index's table
98 and bloat the size of the index, thus potentially slowing searches.
99 Furthermore, B-tree deduplication is never used with indexes
100 that have a non-key column.
102 Columns listed in the <code class="literal">INCLUDE</code> clause don't need
103 appropriate operator classes; the clause can include
104 columns whose data types don't have operator classes defined for
105 a given access method.
107 Expressions are not supported as included columns since they cannot be
108 used in index-only scans.
110 Currently, the B-tree, GiST and SP-GiST index access methods support
111 this feature. In these indexes, the values of columns listed
112 in the <code class="literal">INCLUDE</code> clause are included in leaf tuples
113 which correspond to heap tuples, but are not included in upper-level
114 index entries used for tree navigation.
115 </p></dd><dt><span class="term"><em class="replaceable"><code>name</code></em></span></dt><dd><p>
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. The name of the index must be distinct from the name of any
119 other relation (table, sequence, index, view, materialized view, or
120 foreign table) in that schema.
121 If the name is omitted, <span class="productname">PostgreSQL</span> chooses a
122 suitable name based on the parent table's name and the indexed column
124 </p></dd><dt><span class="term"><code class="literal">ONLY</code></span></dt><dd><p>
125 Indicates not to recurse creating indexes on partitions, if the
126 table is partitioned. The default is to recurse.
127 </p></dd><dt><span class="term"><em class="replaceable"><code>table_name</code></em></span></dt><dd><p>
128 The name (possibly schema-qualified) of the table to be indexed.
129 </p></dd><dt><span class="term"><em class="replaceable"><code>method</code></em></span></dt><dd><p>
130 The name of the index method to be used. Choices are
131 <code class="literal">btree</code>, <code class="literal">hash</code>,
132 <code class="literal">gist</code>, <code class="literal">spgist</code>, <code class="literal">gin</code>,
133 <code class="literal">brin</code>, or user-installed access methods like
134 <a class="link" href="bloom.html" title="F.6. bloom — bloom filter index access method">bloom</a>.
135 The default method is <code class="literal">btree</code>.
136 </p></dd><dt><span class="term"><em class="replaceable"><code>column_name</code></em></span></dt><dd><p>
137 The name of a column of the table.
138 </p></dd><dt><span class="term"><em class="replaceable"><code>expression</code></em></span></dt><dd><p>
139 An expression based on one or more columns of the table. The
140 expression usually must be written with surrounding parentheses,
141 as shown in the syntax. However, the parentheses can be omitted
142 if the expression has the form of a function call.
143 </p></dd><dt><span class="term"><em class="replaceable"><code>collation</code></em></span></dt><dd><p>
144 The name of the collation to use for the index. By default,
145 the index uses the collation declared for the column to be
146 indexed or the result collation of the expression to be
147 indexed. Indexes with non-default collations can be useful for
148 queries that involve expressions using non-default collations.
149 </p></dd><dt><span class="term"><em class="replaceable"><code>opclass</code></em></span></dt><dd><p>
150 The name of an operator class. See below for details.
151 </p></dd><dt><span class="term"><em class="replaceable"><code>opclass_parameter</code></em></span></dt><dd><p>
152 The name of an operator class parameter. See below for details.
153 </p></dd><dt><span class="term"><code class="literal">ASC</code></span></dt><dd><p>
154 Specifies ascending sort order (which is the default).
155 </p></dd><dt><span class="term"><code class="literal">DESC</code></span></dt><dd><p>
156 Specifies descending sort order.
157 </p></dd><dt><span class="term"><code class="literal">NULLS FIRST</code></span></dt><dd><p>
158 Specifies that nulls sort before non-nulls. This is the default
159 when <code class="literal">DESC</code> is specified.
160 </p></dd><dt><span class="term"><code class="literal">NULLS LAST</code></span></dt><dd><p>
161 Specifies that nulls sort after non-nulls. This is the default
162 when <code class="literal">DESC</code> is not specified.
163 </p></dd><dt><span class="term"><code class="literal">NULLS DISTINCT</code><br /></span><span class="term"><code class="literal">NULLS NOT DISTINCT</code></span></dt><dd><p>
164 Specifies whether for a unique index, null values should be considered
165 distinct (not equal). The default is that they are distinct, so that
166 a unique index could contain multiple null values in a column.
167 </p></dd><dt><span class="term"><em class="replaceable"><code>storage_parameter</code></em></span></dt><dd><p>
168 The name of an index-method-specific storage parameter. See
169 <a class="xref" href="sql-createindex.html#SQL-CREATEINDEX-STORAGE-PARAMETERS" title="Index Storage Parameters">Index Storage Parameters</a> below
171 </p></dd><dt><span class="term"><em class="replaceable"><code>tablespace_name</code></em></span></dt><dd><p>
172 The tablespace in which to create the index. If not specified,
173 <a class="xref" href="runtime-config-client.html#GUC-DEFAULT-TABLESPACE">default_tablespace</a> is consulted, or
174 <a class="xref" href="runtime-config-client.html#GUC-TEMP-TABLESPACES">temp_tablespaces</a> for indexes on temporary
176 </p></dd><dt><span class="term"><em class="replaceable"><code>predicate</code></em></span></dt><dd><p>
177 The constraint expression for a partial index.
178 </p></dd></dl></div><div class="refsect2" id="SQL-CREATEINDEX-STORAGE-PARAMETERS"><h3>Index Storage Parameters</h3><p>
179 The optional <code class="literal">WITH</code> clause specifies <em class="firstterm">storage
180 parameters</em> for the index. Each index method has its own set
181 of allowed storage parameters.
183 The B-tree, hash, GiST and SP-GiST index methods all accept this
185 </p><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-FILLFACTOR"><span class="term"><code class="literal">fillfactor</code> (<code class="type">integer</code>)
186 <a id="id-1.9.3.69.6.3.4.1.1.3" class="indexterm"></a>
187 </span> <a href="#INDEX-RELOPTION-FILLFACTOR" class="id_link">#</a></dt><dd><p>
189 the index method will try to pack index pages. For B-trees, leaf pages
190 are filled to this percentage during initial index builds, and also
191 when extending the index at the right (adding new largest key values).
193 subsequently become completely full, they will be split, leading to
194 fragmentation of the on-disk index structure. B-trees use a default
195 fillfactor of 90, but any integer value from 10 to 100 can be selected.
197 B-tree indexes on tables where many inserts and/or updates are
198 anticipated can benefit from lower fillfactor settings at
199 <code class="command">CREATE INDEX</code> time (following bulk loading into the
200 table). Values in the range of 50 - 90 can usefully <span class="quote">“<span class="quote">smooth
201 out</span>”</span> the <span class="emphasis"><em>rate</em></span> of page splits during the
202 early life of the B-tree index (lowering fillfactor like this may even
203 lower the absolute number of page splits, though this effect is highly
204 workload dependent). The B-tree bottom-up index deletion technique
205 described in <a class="xref" href="btree.html#BTREE-DELETION" title="65.1.4.2. Bottom-up Index Deletion">Section 65.1.4.2</a> is dependent on having
206 some <span class="quote">“<span class="quote">extra</span>”</span> space on pages to store <span class="quote">“<span class="quote">extra</span>”</span>
207 tuple versions, and so can be affected by fillfactor (though the effect
208 is usually not significant).
210 In other specific cases it might be useful to increase fillfactor to
211 100 at <code class="command">CREATE INDEX</code> time as a way of maximizing
212 space utilization. You should only consider this when you are
213 completely sure that the table is static (i.e. that it will never be
214 affected by either inserts or updates). A fillfactor setting of 100
215 otherwise risks <span class="emphasis"><em>harming</em></span> performance: even a few
216 updates or inserts will cause a sudden flood of page splits.
218 The other index methods use fillfactor in different but roughly
219 analogous ways; the default fillfactor varies between methods.
220 </p></dd></dl></div><p>
221 B-tree indexes additionally accept this parameter:
222 </p><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-DEDUPLICATE-ITEMS"><span class="term"><code class="literal">deduplicate_items</code> (<code class="type">boolean</code>)
223 <a id="id-1.9.3.69.6.3.6.1.1.3" class="indexterm"></a>
224 </span> <a href="#INDEX-RELOPTION-DEDUPLICATE-ITEMS" class="id_link">#</a></dt><dd><p>
225 Controls usage of the B-tree deduplication technique described
226 in <a class="xref" href="btree.html#BTREE-DEDUPLICATION" title="65.1.4.3. Deduplication">Section 65.1.4.3</a>. Set to
227 <code class="literal">ON</code> or <code class="literal">OFF</code> to enable or
228 disable the optimization. (Alternative spellings of
229 <code class="literal">ON</code> and <code class="literal">OFF</code> are allowed as
230 described in <a class="xref" href="config-setting.html" title="19.1. Setting Parameters">Section 19.1</a>.) The default is
231 <code class="literal">ON</code>.
232 </p><div class="note"><h3 class="title">Note</h3><p>
233 Turning <code class="literal">deduplicate_items</code> off via
234 <code class="command">ALTER INDEX</code> prevents future insertions from
235 triggering deduplication, but does not in itself make existing
236 posting list tuples use the standard tuple representation.
237 </p></div></dd></dl></div><p>
238 GiST indexes additionally accept this parameter:
239 </p><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-BUFFERING"><span class="term"><code class="literal">buffering</code> (<code class="type">enum</code>)
240 <a id="id-1.9.3.69.6.3.8.1.1.3" class="indexterm"></a>
241 </span> <a href="#INDEX-RELOPTION-BUFFERING" class="id_link">#</a></dt><dd><p>
242 Controls whether the buffered build technique described in
243 <a class="xref" href="gist.html#GIST-BUFFERING-BUILD" title="65.2.4.1. GiST Index Build Methods">Section 65.2.4.1</a> is used to build the index. With
244 <code class="literal">OFF</code> buffering is disabled, with <code class="literal">ON</code>
245 it is enabled, and with <code class="literal">AUTO</code> it is initially disabled,
246 but is turned on on-the-fly once the index size reaches
247 <a class="xref" href="runtime-config-query.html#GUC-EFFECTIVE-CACHE-SIZE">effective_cache_size</a>. The default
248 is <code class="literal">AUTO</code>.
249 Note that if sorted build is possible, it will be used instead of
250 buffered build unless <code class="literal">buffering=ON</code> is specified.
251 </p></dd></dl></div><p>
252 GIN indexes accept these parameters:
253 </p><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-FASTUPDATE"><span class="term"><code class="literal">fastupdate</code> (<code class="type">boolean</code>)
254 <a id="id-1.9.3.69.6.3.10.1.1.3" class="indexterm"></a>
255 </span> <a href="#INDEX-RELOPTION-FASTUPDATE" class="id_link">#</a></dt><dd><p>
256 Controls usage of the fast update technique described in
257 <a class="xref" href="gin.html#GIN-FAST-UPDATE" title="65.4.4.1. GIN Fast Update Technique">Section 65.4.4.1</a>.
258 <code class="literal">ON</code> enables fast update, <code class="literal">OFF</code> disables it.
259 The default is <code class="literal">ON</code>.
260 </p><div class="note"><h3 class="title">Note</h3><p>
261 Turning <code class="literal">fastupdate</code> off via <code class="command">ALTER INDEX</code> prevents
262 future insertions from going into the list of pending index entries,
263 but does not in itself flush existing entries. You might want to
264 <code class="command">VACUUM</code> the table or call
265 the <code class="function">gin_clean_pending_list</code>
266 function afterward to ensure the pending list is emptied.
267 </p></div></dd></dl></div><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-GIN-PENDING-LIST-LIMIT"><span class="term"><code class="literal">gin_pending_list_limit</code> (<code class="type">integer</code>)
268 <a id="id-1.9.3.69.6.3.11.1.1.3" class="indexterm"></a>
269 </span> <a href="#INDEX-RELOPTION-GIN-PENDING-LIST-LIMIT" class="id_link">#</a></dt><dd><p>
270 Overrides the global setting of
271 <a class="xref" href="runtime-config-client.html#GUC-GIN-PENDING-LIST-LIMIT">gin_pending_list_limit</a> for this index.
272 This value is specified in kilobytes.
273 </p></dd></dl></div><p>
274 <acronym class="acronym">BRIN</acronym> indexes accept these parameters:
275 </p><div class="variablelist"><dl class="variablelist"><dt id="INDEX-RELOPTION-PAGES-PER-RANGE"><span class="term"><code class="literal">pages_per_range</code> (<code class="type">integer</code>)
276 <a id="id-1.9.3.69.6.3.13.1.1.3" class="indexterm"></a>
277 </span> <a href="#INDEX-RELOPTION-PAGES-PER-RANGE" class="id_link">#</a></dt><dd><p>
278 Defines the number of table blocks that make up one block range for
279 each entry of a <acronym class="acronym">BRIN</acronym> index (see <a class="xref" href="brin.html#BRIN-INTRO" title="65.5.1. Introduction">Section 65.5.1</a>
280 for more details). The default is <code class="literal">128</code>.
281 </p></dd><dt id="INDEX-RELOPTION-AUTOSUMMARIZE"><span class="term"><code class="literal">autosummarize</code> (<code class="type">boolean</code>)
282 <a id="id-1.9.3.69.6.3.13.2.1.3" class="indexterm"></a>
283 </span> <a href="#INDEX-RELOPTION-AUTOSUMMARIZE" class="id_link">#</a></dt><dd><p>
284 Defines whether a summarization run is queued for the previous page
285 range whenever an insertion is detected on the next one
286 (see <a class="xref" href="brin.html#BRIN-OPERATION" title="65.5.1.1. Index Maintenance">Section 65.5.1.1</a> for more details).
287 The default is <code class="literal">off</code>.
288 </p></dd></dl></div></div><div class="refsect2" id="SQL-CREATEINDEX-CONCURRENTLY"><h3>Building Indexes Concurrently</h3><a id="id-1.9.3.69.6.4.2" class="indexterm"></a><p>
289 Creating an index can interfere with regular operation of a database.
290 Normally <span class="productname">PostgreSQL</span> locks the table to be indexed against
291 writes and performs the entire index build with a single scan of the
292 table. Other transactions can still read the table, but if they try to
293 insert, update, or delete rows in the table they will block until the
294 index build is finished. This could have a severe effect if the system is
295 a live production database. Very large tables can take many hours to be
296 indexed, and even for smaller tables, an index build can lock out writers
297 for periods that are unacceptably long for a production system.
299 <span class="productname">PostgreSQL</span> supports building indexes without locking
300 out writes. This method is invoked by specifying the
301 <code class="literal">CONCURRENTLY</code> option of <code class="command">CREATE INDEX</code>.
302 When this option is used,
303 <span class="productname">PostgreSQL</span> must perform two scans of the table, and in
304 addition it must wait for all existing transactions that could potentially
305 modify or use the index to terminate. Thus
306 this method requires more total work than a standard index build and takes
307 significantly longer to complete. However, since it allows normal
308 operations to continue while the index is built, this method is useful for
309 adding new indexes in a production environment. Of course, the extra CPU
310 and I/O load imposed by the index creation might slow other operations.
312 In a concurrent index build, the index is actually entered as an
313 <span class="quote">“<span class="quote">invalid</span>”</span> index into
314 the system catalogs in one transaction, then two table scans occur in
315 two more transactions. Before each table scan, the index build must
316 wait for existing transactions that have modified the table to terminate.
317 After the second scan, the index build must wait for any transactions
318 that have a snapshot (see <a class="xref" href="mvcc.html" title="Chapter 13. Concurrency Control">Chapter 13</a>) predating the second
319 scan to terminate, including transactions used by any phase of concurrent
320 index builds on other tables, if the indexes involved are partial or have
321 columns that are not simple column references.
322 Then finally the index can be marked <span class="quote">“<span class="quote">valid</span>”</span> and ready for use,
323 and the <code class="command">CREATE INDEX</code> command terminates.
324 Even then, however, the index may not be immediately usable for queries:
325 in the worst case, it cannot be used as long as transactions exist that
326 predate the start of the index build.
328 If a problem arises while scanning the table, such as a deadlock or a
329 uniqueness violation in a unique index, the <code class="command">CREATE INDEX</code>
330 command will fail but leave behind an <span class="quote">“<span class="quote">invalid</span>”</span> index. This index
331 will be ignored for querying purposes because it might be incomplete;
332 however it will still consume update overhead. The <span class="application">psql</span>
333 <code class="command">\d</code> command will report such an index as <code class="literal">INVALID</code>:
335 </p><pre class="programlisting">
338 Column | Type | Collation | Nullable | Default
339 --------+---------+-----------+----------+---------
342 "idx" btree (col) INVALID
345 The recommended recovery
346 method in such cases is to drop the index and try again to perform
347 <code class="command">CREATE INDEX CONCURRENTLY</code>. (Another possibility is
348 to rebuild the index with <code class="command">REINDEX INDEX CONCURRENTLY</code>).
350 Another caveat when building a unique index concurrently is that the
351 uniqueness constraint is already being enforced against other transactions
352 when the second table scan begins. This means that constraint violations
353 could be reported in other queries prior to the index becoming available
354 for use, or even in cases where the index build eventually fails. Also,
355 if a failure does occur in the second scan, the <span class="quote">“<span class="quote">invalid</span>”</span> index
356 continues to enforce its uniqueness constraint afterwards.
358 Concurrent builds of expression indexes and partial indexes are supported.
359 Errors occurring in the evaluation of these expressions could cause
360 behavior similar to that described above for unique constraint violations.
362 Regular index builds permit other regular index builds on the
363 same table to occur simultaneously, but only one concurrent index build
364 can 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 is
366 that a regular <code class="command">CREATE INDEX</code> command can be performed
367 within a transaction block, but <code class="command">CREATE INDEX CONCURRENTLY</code>
370 Concurrent builds for indexes on partitioned tables are currently not
371 supported. However, you may concurrently build the index on each
372 partition individually and then finally create the partitioned index
373 non-concurrently in order to reduce the time where writes to the
374 partitioned table will be locked out. In this case, building the
375 partitioned index is a metadata only operation.
376 </p></div></div><div class="refsect1" id="id-1.9.3.69.7"><h2>Notes</h2><p>
377 See <a class="xref" href="indexes.html" title="Chapter 11. Indexes">Chapter 11</a> for information about when indexes can
378 be used, when they are not used, and in which particular situations
381 Currently, only the B-tree, GiST, GIN, and BRIN index methods support
382 multiple-key-column indexes. Whether there can be multiple key
383 columns is independent of whether <code class="literal">INCLUDE</code> columns
384 can be added to the index. Indexes can have up to 32 columns,
385 including <code class="literal">INCLUDE</code> columns.
386 (This limit can be altered when building
387 <span class="productname">PostgreSQL</span>.) Only B-tree currently
388 supports unique indexes.
390 An <em class="firstterm">operator class</em> with optional parameters
391 can be specified for each column of an index.
392 The operator class identifies the operators to be
393 used by the index for that column. For example, a B-tree index on
394 four-byte integers would use the <code class="literal">int4_ops</code> class;
395 this operator class includes comparison functions for four-byte
396 integers. In practice the default operator class for the column's data
397 type is usually sufficient. The main point of having operator classes
398 is that for some data types, there could be more than one meaningful
399 ordering. For example, we might want to sort a complex-number data
400 type either by absolute value or by real part. We could do this by
401 defining two operator classes for the data type and then selecting
402 the proper class when creating an index. More information about
403 operator classes is in <a class="xref" href="indexes-opclass.html" title="11.10. Operator Classes and Operator Families">Section 11.10</a> and in <a class="xref" href="xindex.html" title="36.16. Interfacing Extensions to Indexes">Section 36.16</a>.
405 When <code class="literal">CREATE INDEX</code> is invoked on a partitioned
406 table, the default behavior is to recurse to all partitions to ensure
407 they all have matching indexes.
408 Each partition is first checked to determine whether an equivalent
409 index already exists, and if so, that index will become attached as a
410 partition index to the index being created, which will become its
412 If no matching index exists, a new index will be created and
413 automatically attached; the name of the new index in each partition
414 will be determined as if no index name had been specified in the
416 If the <code class="literal">ONLY</code> option is specified, no recursion
417 is done, and the index is marked invalid.
418 (<code class="command">ALTER INDEX ... ATTACH PARTITION</code> marks the index
419 valid, once all partitions acquire matching indexes.) Note, however,
420 that any partition that is created in the future using
421 <code class="command">CREATE TABLE ... PARTITION OF</code> will automatically
422 have a matching index, regardless of whether <code class="literal">ONLY</code> is
425 For index methods that support ordered scans (currently, only B-tree),
426 the optional clauses <code class="literal">ASC</code>, <code class="literal">DESC</code>, <code class="literal">NULLS
427 FIRST</code>, and/or <code class="literal">NULLS LAST</code> can be specified to modify
428 the sort ordering of the index. Since an ordered index can be
429 scanned either forward or backward, it is not normally useful to create a
430 single-column <code class="literal">DESC</code> index — that sort ordering is already
431 available with a regular index. The value of these options is that
432 multicolumn indexes can be created that match the sort ordering requested
433 by a mixed-ordering query, such as <code class="literal">SELECT ... ORDER BY x ASC, y
434 DESC</code>. The <code class="literal">NULLS</code> options are useful if you need to support
435 <span class="quote">“<span class="quote">nulls sort low</span>”</span> behavior, rather than the default <span class="quote">“<span class="quote">nulls
436 sort high</span>”</span>, in queries that depend on indexes to avoid sorting steps.
438 The system regularly collects statistics on all of a table's
439 columns. Newly-created non-expression indexes can immediately
440 use these statistics to determine an index's usefulness.
441 For new expression indexes, it is necessary to run <a class="link" href="sql-analyze.html" title="ANALYZE"><code class="command">ANALYZE</code></a> or wait for
442 the <a class="link" href="routine-vacuuming.html#AUTOVACUUM" title="24.1.6. The Autovacuum Daemon">autovacuum daemon</a> to analyze
443 the table to generate statistics for these indexes.
445 While <code class="command">CREATE INDEX</code> is running, the <a class="xref" href="runtime-config-client.html#GUC-SEARCH-PATH">search_path</a> is temporarily changed to <code class="literal">pg_catalog,
448 For most index methods, the speed of creating an index is
449 dependent on the setting of <a class="xref" href="runtime-config-resource.html#GUC-MAINTENANCE-WORK-MEM">maintenance_work_mem</a>.
450 Larger values will reduce the time needed for index creation, so long
451 as you don't make it larger than the amount of memory really available,
452 which would drive the machine into swapping.
454 <span class="productname">PostgreSQL</span> can build indexes while
455 leveraging multiple CPUs in order to process the table rows faster.
456 This feature is known as <em class="firstterm">parallel index
457 build</em>. For index methods that support building indexes
458 in parallel (currently, B-tree, GIN, and BRIN),
459 <code class="varname">maintenance_work_mem</code> specifies the maximum
460 amount of memory that can be used by each index build operation as
461 a whole, regardless of how many worker processes were started.
462 Generally, a cost model automatically determines how many worker
463 processes should be requested, if any.
465 Parallel index builds may benefit from increasing
466 <code class="varname">maintenance_work_mem</code> where an equivalent serial
467 index build will see little or no benefit. Note that
468 <code class="varname">maintenance_work_mem</code> may influence the number of
469 worker processes requested, since parallel workers must have at
470 least a <code class="literal">32MB</code> share of the total
471 <code class="varname">maintenance_work_mem</code> budget. There must also be
472 a remaining <code class="literal">32MB</code> share for the leader process.
473 Increasing <a class="xref" href="runtime-config-resource.html#GUC-MAX-PARALLEL-MAINTENANCE-WORKERS">max_parallel_maintenance_workers</a>
474 may allow more workers to be used, which will reduce the time
475 needed for index creation, so long as the index build is not
476 already I/O bound. Of course, there should also be sufficient
477 CPU capacity that would otherwise lie idle.
479 Setting a value for <code class="literal">parallel_workers</code> via <a class="link" href="sql-altertable.html" title="ALTER TABLE"><code class="command">ALTER TABLE</code></a> directly controls how many parallel
480 worker processes will be requested by a <code class="command">CREATE
481 INDEX</code> against the table. This bypasses the cost model
482 completely, and prevents <code class="varname">maintenance_work_mem</code>
483 from affecting how many parallel workers are requested. Setting
484 <code class="literal">parallel_workers</code> to 0 via <code class="command">ALTER
485 TABLE</code> will disable parallel index builds on the table in
487 </p><div class="tip"><h3 class="title">Tip</h3><p>
488 You might want to reset <code class="literal">parallel_workers</code> after
489 setting it as part of tuning an index build. This avoids
490 inadvertent changes to query plans, since
491 <code class="literal">parallel_workers</code> affects
492 <span class="emphasis"><em>all</em></span> parallel table scans.
494 While <code class="command">CREATE INDEX</code> with the
495 <code class="literal">CONCURRENTLY</code> option supports parallel builds
496 without special restrictions, only the first table scan is actually
497 performed in parallel.
499 Use <a class="link" href="sql-dropindex.html" title="DROP INDEX"><code class="command">DROP INDEX</code></a>
502 Like any long-running transaction, <code class="command">CREATE INDEX</code> on a
503 table can affect which tuples can be removed by concurrent
504 <code class="command">VACUUM</code> on any other table.
506 Prior releases of <span class="productname">PostgreSQL</span> also had an
507 R-tree index method. This method has been removed because
508 it had no significant advantages over the GiST method.
509 If <code class="literal">USING rtree</code> is specified, <code class="command">CREATE INDEX</code>
510 will interpret it as <code class="literal">USING gist</code>, to simplify conversion
511 of old databases to GiST.
513 Each backend running <code class="command">CREATE INDEX</code> will report its
514 progress in the <code class="structname">pg_stat_progress_create_index</code>
515 view. See <a class="xref" href="progress-reporting.html#CREATE-INDEX-PROGRESS-REPORTING" title="27.4.4. CREATE INDEX Progress Reporting">Section 27.4.4</a> for details.
516 </p></div><div class="refsect1" id="id-1.9.3.69.8"><h2>Examples</h2><p>
517 To create a unique B-tree index on the column <code class="literal">title</code> in
518 the table <code class="literal">films</code>:
519 </p><pre class="programlisting">
520 CREATE UNIQUE INDEX title_idx ON films (title);
523 To create a unique B-tree index on the column <code class="literal">title</code>
524 with included columns <code class="literal">director</code>
525 and <code class="literal">rating</code> in the table <code class="literal">films</code>:
526 </p><pre class="programlisting">
527 CREATE UNIQUE INDEX title_idx ON films (title) INCLUDE (director, rating);
530 To create a B-Tree index with deduplication disabled:
531 </p><pre class="programlisting">
532 CREATE INDEX title_idx ON films (title) WITH (deduplicate_items = off);
535 To create an index on the expression <code class="literal">lower(title)</code>,
536 allowing efficient case-insensitive searches:
537 </p><pre class="programlisting">
538 CREATE INDEX ON films ((lower(title)));
540 (In this example we have chosen to omit the index name, so the system
541 will choose a name, typically <code class="literal">films_lower_idx</code>.)
543 To create an index with non-default collation:
544 </p><pre class="programlisting">
545 CREATE INDEX title_idx_german ON films (title COLLATE "de_DE");
548 To create an index with non-default sort ordering of nulls:
549 </p><pre class="programlisting">
550 CREATE INDEX title_idx_nulls_low ON films (title NULLS FIRST);
553 To create an index with non-default fill factor:
554 </p><pre class="programlisting">
555 CREATE UNIQUE INDEX title_idx ON films (title) WITH (fillfactor = 70);
558 To create a <acronym class="acronym">GIN</acronym> index with fast updates disabled:
559 </p><pre class="programlisting">
560 CREATE INDEX gin_idx ON documents_table USING GIN (locations) WITH (fastupdate = off);
563 To create an index on the column <code class="literal">code</code> in the table
564 <code class="literal">films</code> and have the index reside in the tablespace
565 <code class="literal">indexspace</code>:
566 </p><pre class="programlisting">
567 CREATE INDEX code_idx ON films (code) TABLESPACE indexspace;
570 To create a GiST index on a point attribute so that we
571 can efficiently use box operators on the result of the
573 </p><pre class="programlisting">
574 CREATE INDEX pointloc
575 ON points USING gist (box(location,location));
577 WHERE box(location,location) && '(0,0),(1,1)'::box;
580 To create an index without locking out writes to the table:
581 </p><pre class="programlisting">
582 CREATE INDEX CONCURRENTLY sales_quantity_index ON sales_table (quantity);
583 </pre></div><div class="refsect1" id="id-1.9.3.69.9"><h2>Compatibility</h2><p>
584 <code class="command">CREATE INDEX</code> is a
585 <span class="productname">PostgreSQL</span> language extension. There
586 are no provisions for indexes in the SQL standard.
587 </p></div><div class="refsect1" id="id-1.9.3.69.10"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-alterindex.html" title="ALTER INDEX"><span class="refentrytitle">ALTER INDEX</span></a>, <a class="xref" href="sql-dropindex.html" title="DROP INDEX"><span class="refentrytitle">DROP INDEX</span></a>, <a class="xref" href="sql-reindex.html" title="REINDEX"><span class="refentrytitle">REINDEX</span></a>, <a class="xref" href="progress-reporting.html#CREATE-INDEX-PROGRESS-REPORTING" title="27.4.4. CREATE INDEX Progress Reporting">Section 27.4.4</a></span></div></div><div class="navfooter"><hr /><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-creategroup.html" title="CREATE GROUP">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-createlanguage.html" title="CREATE LANGUAGE">Next</a></td></tr><tr><td width="40%" align="left" valign="top">CREATE GROUP </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 18.0 Documentation">Home</a></td><td width="40%" align="right" valign="top"> CREATE LANGUAGE</td></tr></table></div></body></html>