1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379
|
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>GiST and GIN Index Types</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 9.1.15 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Full Text Search"
HREF="textsearch.html"><LINK
REL="PREVIOUS"
TITLE="Testing and Debugging Text Search"
HREF="textsearch-debugging.html"><LINK
REL="NEXT"
TITLE="psql Support"
HREF="textsearch-psql.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2015-02-02T21:03:01"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
><A
HREF="index.html"
>PostgreSQL 9.1.15 Documentation</A
></TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
TITLE="Testing and Debugging Text Search"
HREF="textsearch-debugging.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="textsearch.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 12. Full Text Search</TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="psql Support"
HREF="textsearch-psql.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="TEXTSEARCH-INDEXES"
>12.9. GiST and GIN Index Types</A
></H1
><P
> There are two kinds of indexes that can be used to speed up full text
searches.
Note that indexes are not mandatory for full text searching, but in
cases where a column is searched on a regular basis, an index is
usually desirable.
<P
></P
></P><DIV
CLASS="VARIABLELIST"
><DL
><DT
><PRE
CLASS="SYNOPSIS"
>CREATE INDEX <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> ON <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
> USING gist(<TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
>);</PRE
></DT
><DD
><P
> Creates a GiST (Generalized Search Tree)-based index.
The <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> can be of <TT
CLASS="TYPE"
>tsvector</TT
> or
<TT
CLASS="TYPE"
>tsquery</TT
> type.
</P
></DD
><DT
><PRE
CLASS="SYNOPSIS"
>CREATE INDEX <TT
CLASS="REPLACEABLE"
><I
>name</I
></TT
> ON <TT
CLASS="REPLACEABLE"
><I
>table</I
></TT
> USING gin(<TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
>);</PRE
></DT
><DD
><P
> Creates a GIN (Generalized Inverted Index)-based index.
The <TT
CLASS="REPLACEABLE"
><I
>column</I
></TT
> must be of <TT
CLASS="TYPE"
>tsvector</TT
> type.
</P
></DD
></DL
></DIV
><P>
</P
><P
> There are substantial performance differences between the two index types,
so it is important to understand their characteristics.
</P
><P
> A GiST index is <I
CLASS="FIRSTTERM"
>lossy</I
>, meaning that the index
may produce false matches, and it is necessary
to check the actual table row to eliminate such false matches.
(<SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> does this automatically when needed.)
GiST indexes are lossy because each document is represented in the
index by a fixed-length signature. The signature is generated by hashing
each word into a single bit in an n-bit string, with all these bits OR-ed
together to produce an n-bit document signature. When two words hash to
the same bit position there will be a false match. If all words in
the query have matches (real or false) then the table row must be
retrieved to see if the match is correct.
</P
><P
> Lossiness causes performance degradation due to unnecessary fetches of table
records that turn out to be false matches. Since random access to table
records is slow, this limits the usefulness of GiST indexes. The
likelihood of false matches depends on several factors, in particular the
number of unique words, so using dictionaries to reduce this number is
recommended.
</P
><P
> GIN indexes are not lossy for standard queries, but their performance
depends logarithmically on the number of unique words.
(However, GIN indexes store only the words (lexemes) of <TT
CLASS="TYPE"
>tsvector</TT
>
values, and not their weight labels. Thus a table row recheck is needed
when using a query that involves weights.)
</P
><P
> In choosing which index type to use, GiST or GIN, consider these
performance differences:
<P
></P
></P><UL
COMPACT="COMPACT"
><LI
STYLE="list-style-type: disc"
><P
> GIN index lookups are about three times faster than GiST
</P
></LI
><LI
STYLE="list-style-type: disc"
><P
> GIN indexes take about three times longer to build than GiST
</P
></LI
><LI
STYLE="list-style-type: disc"
><P
> GIN indexes are moderately slower to update than GiST indexes, but
about 10 times slower if fast-update support was disabled
(see <A
HREF="gin-implementation.html#GIN-FAST-UPDATE"
>Section 54.3.1</A
> for details)
</P
></LI
><LI
STYLE="list-style-type: disc"
><P
> GIN indexes are two-to-three times larger than GiST indexes
</P
></LI
></UL
><P>
</P
><P
> As a rule of thumb, <ACRONYM
CLASS="ACRONYM"
>GIN</ACRONYM
> indexes are best for static data
because lookups are faster. For dynamic data, GiST indexes are
faster to update. Specifically, <ACRONYM
CLASS="ACRONYM"
>GiST</ACRONYM
> indexes are very
good for dynamic data and fast if the number of unique words (lexemes) is
under 100,000, while <ACRONYM
CLASS="ACRONYM"
>GIN</ACRONYM
> indexes will handle 100,000+
lexemes better but are slower to update.
</P
><P
> Note that <ACRONYM
CLASS="ACRONYM"
>GIN</ACRONYM
> index build time can often be improved
by increasing <A
HREF="runtime-config-resource.html#GUC-MAINTENANCE-WORK-MEM"
>maintenance_work_mem</A
>, while
<ACRONYM
CLASS="ACRONYM"
>GiST</ACRONYM
> index build time is not sensitive to that
parameter.
</P
><P
> Partitioning of big collections and the proper use of GiST and GIN indexes
allows the implementation of very fast searches with online update.
Partitioning can be done at the database level using table inheritance,
or by distributing documents over
servers and collecting search results using the <A
HREF="dblink.html"
>dblink</A
>
module. The latter is possible because ranking functions use
only local information.
</P
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="textsearch-debugging.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="textsearch-psql.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Testing and Debugging Text Search</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="textsearch.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><SPAN
CLASS="APPLICATION"
>psql</SPAN
> Support</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>
|