postgresql/doc/src/sgml/gist.sgml

671 lines
21 KiB
Plaintext
Raw Normal View History

<!-- $PostgreSQL: pgsql/doc/src/sgml/gist.sgml,v 1.31 2009/06/12 19:48:53 tgl Exp $ -->
<chapter id="GiST">
<title>GiST Indexes</title>
<indexterm>
<primary>index</primary>
<secondary>GiST</secondary>
</indexterm>
2005-11-07 18:36:47 +01:00
<sect1 id="gist-intro">
<title>Introduction</title>
<para>
<acronym>GiST</acronym> stands for Generalized Search Tree. It is a
balanced, tree-structured access method, that acts as a base template in
2005-11-07 18:36:47 +01:00
which to implement arbitrary indexing schemes. B-trees, R-trees and many
other indexing schemes can be implemented in <acronym>GiST</acronym>.
</para>
<para>
One advantage of <acronym>GiST</acronym> is that it allows the development
of custom data types with the appropriate access methods, by
an expert in the domain of the data type, rather than a database expert.
</para>
<para>
Some of the information here is derived from the University of California
at Berkeley's GiST Indexing Project
<ulink url="http://gist.cs.berkeley.edu/">web site</ulink> and
Marcel Kornacker's thesis,
2005-10-21 15:59:05 +02:00
<ulink url="http://www.sai.msu.su/~megera/postgres/gist/papers/concurrency/access-methods-for-next-generation.pdf.gz">
Access Methods for Next-Generation Database Systems</ulink>.
The <acronym>GiST</acronym>
implementation in <productname>PostgreSQL</productname> is primarily
maintained by Teodor Sigaev and Oleg Bartunov, and there is more
information on their
<ulink url="http://www.sai.msu.su/~megera/postgres/gist/">web site</ulink>.
</para>
</sect1>
<sect1 id="gist-extensibility">
<title>Extensibility</title>
<para>
Traditionally, implementing a new index access method meant a lot of
difficult work. It was necessary to understand the inner workings of the
database, such as the lock manager and Write-Ahead Log. The
<acronym>GiST</acronym> interface has a high level of abstraction,
requiring the access method implementer only to implement the semantics of
the data type being accessed. The <acronym>GiST</acronym> layer itself
takes care of concurrency, logging and searching the tree structure.
</para>
<para>
This extensibility should not be confused with the extensibility of the
other standard search trees in terms of the data they can handle. For
2005-11-07 18:36:47 +01:00
example, <productname>PostgreSQL</productname> supports extensible B-trees
and hash indexes. That means that you can use
<productname>PostgreSQL</productname> to build a B-tree or hash over any
data type you want. But B-trees only support range predicates
(<literal>&lt;</literal>, <literal>=</literal>, <literal>&gt;</literal>),
2005-11-07 18:36:47 +01:00
and hash indexes only support equality queries.
</para>
<para>
So if you index, say, an image collection with a
2005-11-07 18:36:47 +01:00
<productname>PostgreSQL</productname> B-tree, you can only issue queries
such as <quote>is imagex equal to imagey</quote>, <quote>is imagex less
than imagey</quote> and <quote>is imagex greater than imagey</quote>.
Depending on how you define <quote>equals</quote>, <quote>less than</quote>
and <quote>greater than</quote> in this context, this could be useful.
However, by using a <acronym>GiST</acronym> based index, you could create
ways to ask domain-specific questions, perhaps <quote>find all images of
horses</quote> or <quote>find all over-exposed images</quote>.
</para>
<para>
All it takes to get a <acronym>GiST</acronym> access method up and running
is to implement seven user-defined methods, which define the behavior of
keys in the tree. Of course these methods have to be pretty fancy to
2005-11-07 18:36:47 +01:00
support fancy queries, but for all the standard queries (B-trees,
R-trees, etc.) they're relatively straightforward. In short,
<acronym>GiST</acronym> combines extensibility along with generality, code
reuse, and a clean interface.
</para>
</sect1>
<sect1 id="gist-implementation">
<title>Implementation</title>
<para>
There are seven methods that an index operator class for
<acronym>GiST</acronym> must provide. Correctness of the index is ensured
by proper implementation of the <function>same</>, <function>consistent</>
and <function>union</> methods, while efficiency (size and speed) of the
index will depend on the <function>penalty</> and <function>picksplit</>
methods.
The remaining two methods are <function>compress</> and
<function>decompress</>, which allow an index to have internal tree data of
a different type than the data it indexes. The leaves are to be of the
indexed data type, while the other tree nodes can be of any C struct (but
you still have to follow <productname>PostgreSQL</> datatype rules here,
see about <literal>varlena</> for variable sized data). If the tree's
internal data type exists at the SQL level, the <literal>STORAGE</> option
of the <command>CREATE OPERATOR CLASS</> command can be used.
</para>
<variablelist>
<varlistentry>
<term><function>consistent</></term>
<listitem>
<para>
Given an index entry <literal>p</> and a query value <literal>q</>,
this function determines whether the index entry is
<quote>consistent</> with the query; that is, could the predicate
<quote><replaceable>indexed_column</>
<replaceable>indexable_operator</> <literal>q</></quote> be true for
any row represented by the index entry? For a leaf index entry this is
equivalent to testing the indexable condition, while for an internal
tree node this determines whether it is necessary to scan the subtree
of the index represented by the tree node. When the result is
<literal>true</>, a <literal>recheck</> flag must also be returned.
This indicates whether the predicate is certainly true or only possibly
true. If <literal>recheck</> = <literal>false</> then the index has
tested the predicate condition exactly, whereas if <literal>recheck</>
= <literal>true</> the row is only a candidate match. In that case the
system will automatically evaluate the
<replaceable>indexable_operator</> against the actual row value to see
if it is really a match. This convention allows
<acronym>GiST</acronym> to support both lossless and lossy index
structures.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_consistent(internal, data_type, smallint, oid, internal)
RETURNS bool
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_consistent(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_consistent);
Datum
my_consistent(PG_FUNCTION_ARGS)
{
GISTENTRY *entry = (GISTENTRY *) PG_GETARG_POINTER(0);
data_type *query = PG_GETARG_DATA_TYPE_P(1);
StrategyNumber strategy = (StrategyNumber) PG_GETARG_UINT16(2);
/* Oid subtype = PG_GETARG_OID(3); */
bool *recheck = (bool *) PG_GETARG_POINTER(4);
data_type *key = DatumGetDataType(entry-&gt;key);
bool retval;
/*
* determine return value as a function of strategy, key and query.
*
* Use GIST_LEAF(entry) to know where you're called in the index tree,
* which comes handy when supporting the = operator for example (you could
* check for non empty union() in non-leaf nodes and equality in leaf
* nodes).
*/
*recheck = true; /* or false if check is exact */
PG_RETURN_BOOL(retval);
}
</programlisting>
Here, <varname>key</> is an element in the index and <varname>query</>
the value being looked up in the index. The <literal>StrategyNumber</>
parameter indicates which operator of your operator class is being
applied &mdash; it matches one of the operator numbers in the
<command>CREATE OPERATOR CLASS</> command. Depending on what operators
you have included in the class, the data type of <varname>query</> could
vary with the operator, but the above skeleton assumes it doesn't.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>union</></term>
<listitem>
<para>
This method consolidates information in the tree. Given a set of
entries, this function generates a new index entry that represents
all the given entries.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_union(internal, internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_union(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_union);
Datum
my_union(PG_FUNCTION_ARGS)
{
GistEntryVector *entryvec = (GistEntryVector *) PG_GETARG_POINTER(0);
GISTENTRY *ent = entryvec-&gt;vector;
data_type *out,
*tmp,
*old;
int numranges,
i = 0;
numranges = entryvec-&gt;n;
tmp = DatumGetDataType(ent[0].key);
out = tmp;
if (numranges == 1)
{
out = data_type_deep_copy(tmp);
PG_RETURN_DATA_TYPE_P(out);
}
for (i = 1; i &lt; numranges; i++)
{
old = out;
tmp = DatumGetDataType(ent[i].key);
out = my_union_implementation(out, tmp);
}
PG_RETURN_DATA_TYPE_P(out);
}
</programlisting>
</para>
<para>
As you can see, in this skeleton we're dealing with a data type
where <literal>union(X, Y, Z) = union(union(X, Y), Z)</>. It's easy
enough to support data types where this is not the case, by
implementing the proper union algorithm in this
<acronym>GiST</> support method.
</para>
<para>
The <function>union</> implementation function should return a
pointer to newly <function>palloc()</>ed memory. You can't just
return whatever the input is.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>compress</></term>
<listitem>
<para>
Converts the data item into a format suitable for physical storage in
an index page.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_compress(internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_compress(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_compress);
Datum
my_compress(PG_FUNCTION_ARGS)
{
GISTENTRY *entry = (GISTENTRY *) PG_GETARG_POINTER(0);
GISTENTRY *retval;
if (entry-&gt;leafkey)
{
/* replace entry-&gt;key with a compressed version */
compressed_data_type *compressed_data = palloc(sizeof(compressed_data_type));
/* fill *compressed_data from entry-&gt;key ... */
retval = palloc(sizeof(GISTENTRY));
gistentryinit(*retval, PointerGetDatum(compressed_data),
entry-&gt;rel, entry-&gt;page, entry-&gt;offset, FALSE);
}
else
{
/* typically we needn't do anything with non-leaf entries */
retval = entry;
}
PG_RETURN_POINTER(retval);
}
</programlisting>
</para>
<para>
You have to adapt <replaceable>compressed_data_type</> to the specific
type you're converting to in order to compress your leaf nodes, of
course.
</para>
<para>
Depending on your needs, you could also need to care about
compressing <literal>NULL</> values in there, storing for example
<literal>(Datum) 0</> like <literal>gist_circle_compress</> does.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>decompress</></term>
<listitem>
<para>
The reverse of the <function>compress</function> method. Converts the
index representation of the data item into a format that can be
manipulated by the database.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_decompress(internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_decompress(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_decompress);
Datum
my_decompress(PG_FUNCTION_ARGS)
{
PG_RETURN_POINTER(PG_GETARG_POINTER(0));
}
</programlisting>
The above skeleton is suitable for the case where no decompression
is needed.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>penalty</></term>
<listitem>
<para>
Returns a value indicating the <quote>cost</quote> of inserting the new
entry into a particular branch of the tree. Items will be inserted
down the path of least <function>penalty</function> in the tree.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_penalty(internal, internal, internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT; -- in some cases penalty functions need not be strict
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_penalty(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_penalty);
Datum
my_penalty(PG_FUNCTION_ARGS)
{
GISTENTRY *origentry = (GISTENTRY *) PG_GETARG_POINTER(0);
GISTENTRY *newentry = (GISTENTRY *) PG_GETARG_POINTER(1);
float *penalty = (float *) PG_GETARG_POINTER(2);
data_type *orig = DatumGetDataType(origentry-&gt;key);
data_type *new = DatumGetDataType(newentry-&gt;key);
*penalty = my_penalty_implementation(orig, new);
PG_RETURN_POINTER(penalty);
}
</programlisting>
</para>
<para>
The <function>penalty</> function is crucial to good performance of
the index. It'll get used at insertion time to determine which branch
to follow when choosing where to add the new entry in the tree. At
query time, the more balanced the index, the quicker the lookup.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>picksplit</></term>
<listitem>
<para>
When an index page split is necessary, this function decides which
entries on the page are to stay on the old page, and which are to move
to the new page.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_picksplit(internal, internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_picksplit(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_picksplit);
Datum
my_picksplit(PG_FUNCTION_ARGS)
{
GistEntryVector *entryvec = (GistEntryVector *) PG_GETARG_POINTER(0);
OffsetNumber maxoff = entryvec-&gt;n - 1;
GISTENTRY *ent = entryvec-&gt;vector;
GIST_SPLITVEC *v = (GIST_SPLITVEC *) PG_GETARG_POINTER(1);
int i,
nbytes;
OffsetNumber *left,
*right;
data_type *tmp_union;
data_type *unionL;
data_type *unionR;
GISTENTRY **raw_entryvec;
maxoff = entryvec-&gt;n - 1;
nbytes = (maxoff + 1) * sizeof(OffsetNumber);
v-&gt;spl_left = (OffsetNumber *) palloc(nbytes);
left = v-&gt;spl_left;
v-&gt;spl_nleft = 0;
v-&gt;spl_right = (OffsetNumber *) palloc(nbytes);
right = v-&gt;spl_right;
v-&gt;spl_nright = 0;
unionL = NULL;
unionR = NULL;
/* Initialize the raw entry vector. */
raw_entryvec = (GISTENTRY **) malloc(entryvec-&gt;n * sizeof(void *));
for (i = FirstOffsetNumber; i &lt;= maxoff; i = OffsetNumberNext(i))
raw_entryvec[i] = &amp;(entryvec-&gt;vector[i]);
for (i = FirstOffsetNumber; i &lt;= maxoff; i = OffsetNumberNext(i))
{
int real_index = raw_entryvec[i] - entryvec-&gt;vector;
tmp_union = DatumGetDataType(entryvec-&gt;vector[real_index].key);
Assert(tmp_union != NULL);
/*
* Choose where to put the index entries and update unionL and unionR
* accordingly. Append the entries to either v_spl_left or
* v_spl_right, and care about the counters.
*/
if (my_choice_is_left(unionL, curl, unionR, curr))
{
if (unionL == NULL)
unionL = tmp_union;
else
unionL = my_union_implementation(unionL, tmp_union);
*left = real_index;
++left;
++(v-&gt;spl_nleft);
}
else
{
/*
* Same on the right
*/
}
}
v-&gt;spl_ldatum = DataTypeGetDatum(unionL);
v-&gt;spl_rdatum = DataTypeGetDatum(unionR);
PG_RETURN_POINTER(v);
}
</programlisting>
</para>
<para>
Like <function>penalty</>, the <function>picksplit</> function
is crucial to good performance of the index. Designing suitable
<function>penalty</> and <function>picksplit</> implementations
is where the challenge of implementing well-performing
<acronym>GiST</> indexes lies.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><function>same</></term>
<listitem>
<para>
Returns true if two index entries are identical, false otherwise.
</para>
<para>
The <acronym>SQL</> declaration of the function must look like this:
<programlisting>
CREATE OR REPLACE FUNCTION my_same(internal, internal, internal)
RETURNS internal
AS 'MODULE_PATHNAME'
LANGUAGE C STRICT;
</programlisting>
And the matching code in the C module could then follow this skeleton:
<programlisting>
Datum my_same(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(my_same);
Datum
my_same(PG_FUNCTION_ARGS)
{
prefix_range *v1 = PG_GETARG_PREFIX_RANGE_P(0);
prefix_range *v2 = PG_GETARG_PREFIX_RANGE_P(1);
bool *result = (bool *) PG_GETARG_POINTER(2);
*result = my_eq(v1, v2);
PG_RETURN_POINTER(result);
}
</programlisting>
For historical reasons, the <function>same</> function doesn't
just return a boolean result; instead it has to store the flag
at the location indicated by the third argument.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect1>
<sect1 id="gist-examples">
<title>Examples</title>
<para>
The <productname>PostgreSQL</productname> source distribution includes
several examples of index methods implemented using
<acronym>GiST</acronym>. The core system currently provides text search
support (indexing for <type>tsvector</> and <type>tsquery</>) as well as
R-Tree equivalent functionality for some of the built-in geometric data types
(see <filename>src/backend/access/gist/gistproc.c</>). The following
<filename>contrib</> modules also contain <acronym>GiST</acronym>
operator classes:
</para>
<variablelist>
<varlistentry>
<term>btree_gist</term>
<listitem>
2005-11-05 00:14:02 +01:00
<para>B-Tree equivalent functionality for several data types</para>
</listitem>
</varlistentry>
<varlistentry>
<term>cube</term>
<listitem>
2006-10-23 20:10:32 +02:00
<para>Indexing for multidimensional cubes</para>
</listitem>
</varlistentry>
<varlistentry>
<term>hstore</term>
<listitem>
<para>Module for storing (key, value) pairs</para>
</listitem>
</varlistentry>
<varlistentry>
<term>intarray</term>
<listitem>
<para>RD-Tree for one-dimensional array of int4 values</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ltree</term>
<listitem>
<para>Indexing for tree-like structures</para>
</listitem>
</varlistentry>
<varlistentry>
<term>pg_trgm</term>
<listitem>
<para>Text similarity using trigram matching</para>
</listitem>
</varlistentry>
<varlistentry>
<term>seg</term>
<listitem>
<para>Indexing for <quote>float ranges</quote></para>
</listitem>
</varlistentry>
</variablelist>
</sect1>
<sect1 id="gist-recovery">
<title>Crash Recovery</title>
<para>
Usually, replay of the WAL log is sufficient to restore the integrity
of a GiST index following a database crash. However, there are some
corner cases in which the index state is not fully rebuilt. The index
will still be functionally correct, but there might be some performance
degradation. When this occurs, the index can be repaired by
<command>VACUUM</>ing its table, or by rebuilding the index using
<command>REINDEX</>. In some cases a plain <command>VACUUM</> is
not sufficient, and either <command>VACUUM FULL</> or <command>REINDEX</>
is needed. The need for one of these procedures is indicated by occurrence
of this log message during crash recovery:
<programlisting>
LOG: index NNN/NNN/NNN needs VACUUM or REINDEX to finish crash recovery
</programlisting>
or this log message during routine index insertions:
<programlisting>
LOG: index "FOO" needs VACUUM or REINDEX to finish crash recovery
</programlisting>
If a plain <command>VACUUM</> finds itself unable to complete recovery
fully, it will return a notice:
<programlisting>
NOTICE: index "FOO" needs VACUUM FULL or REINDEX to finish crash recovery
</programlisting>
</para>
</sect1>
</chapter>