Sophie

Sophie

distrib > Mandriva > 2008.1 > x86_64 > media > main-testing > by-pkgid > bab02a23fa9f3df8d66a9a3231b50245 > files > 845

postgresql8.3-docs-8.3.6-2mdv2008.1.x86_64.rpm

<!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 8.3.6 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="2009-02-03T04:34:16"></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"
>PostgreSQL 8.3.6 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="textsearch-debugging.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="textsearch.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 12. Full Text Search</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="textsearch.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
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
><A
NAME="AEN19293"
></A
><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 will
   usually be 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 which to use.
  </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; for
   example, in the query plan below, the <TT
CLASS="LITERAL"
>Filter:</TT
>
   line indicates the index output will be rechecked:

</P><PRE
CLASS="PROGRAMLISTING"
>EXPLAIN SELECT * FROM apod WHERE textsearch @@ to_tsquery('supernovae');
                               QUERY PLAN
-------------------------------------------------------------------------
 Index Scan using textsearch_gidx on apod  (cost=0.00..12.29 rows=2 width=1469)
   Index Cond: (textsearch @@ '''supernova'''::tsquery)
   Filter: (textsearch @@ '''supernova'''::tsquery)</PRE
><P>

   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 random 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 useless 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 but their performance depends logarithmically on
   the number of unique words.
  </P
><P
>   Actually, GIN indexes store only the words (lexemes) of <TT
CLASS="TYPE"
>tsvector</TT
>
   values, and not their weight labels.  Thus, while a GIN index can be
   considered non-lossy for a query that does not specify weights, it is
   lossy for one that does.  Thus a table row recheck is needed when using
   a query that involves weights.  Unfortunately, in the current design of
   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>, whether a recheck is needed is a static
   property of a particular operator, and not something that can be enabled
   or disabled on-the-fly depending on the values given to the operator.
   To deal with this situation without imposing the overhead of rechecks
   on queries that do not need them, the following approach has been
   adopted:
  </P
><P
></P
><UL
COMPACT="COMPACT"
><LI
STYLE="list-style-type: disc"
><P
>     The standard text match operator <TT
CLASS="LITERAL"
>@@</TT
> is marked as non-lossy
     for GIN indexes.
    </P
></LI
><LI
STYLE="list-style-type: disc"
><P
>     An additional match operator <TT
CLASS="LITERAL"
>@@@</TT
> is provided, and marked
     as lossy for GIN indexes.  This operator behaves exactly like
     <TT
CLASS="LITERAL"
>@@</TT
> otherwise.
    </P
></LI
><LI
STYLE="list-style-type: disc"
><P
>     When a GIN index search is initiated with the <TT
CLASS="LITERAL"
>@@</TT
> operator,
     the index support code will throw an error if the query specifies any
     weights.  This protects against giving wrong answers due to failure
     to recheck the weights.
    </P
></LI
></UL
><P
>   In short, you must use <TT
CLASS="LITERAL"
>@@@</TT
> rather than <TT
CLASS="LITERAL"
>@@</TT
> to
   perform GIN index searches on queries that involve weight restrictions.
   For queries that do not have weight restrictions, either operator will
   work, but <TT
CLASS="LITERAL"
>@@</TT
> will be faster.
   This awkwardness will probably be addressed in a future release of
   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>.
  </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 about ten times slower to update than GiST
     </P
></LI
><LI
STYLE="list-style-type: disc"
><P
>      GIN indexes are two-to-three times larger than GiST
     </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
   and <TT
CLASS="VARNAME"
>constraint_exclusion</TT
>, or by distributing documents over
   servers and collecting search results using the <TT
CLASS="FILENAME"
>contrib/dblink</TT
>
   extension 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
>